ALTER TABLE AlarmRangeLimit
ADD IsDefault INT NOT NULL DEFAULT 1
GO

ALTER TABLE BreakerOperation
ADD StatusBitChatter INT NOT NULL DEFAULT 0
GO

ALTER TABLE BreakerOperation
ADD StatusTiming FLOAT NOT NULL DEFAULT 0
GO

ALTER TABLE BreakerOperation
ADD DcOffsetDetected INT NOT NULL DEFAULT 0
GO

ALTER TABLE BreakerOperation
ADD UpdatedBy VARCHAR(50) NULL
GO

ALTER TABLE Event
ADD UpdatedBy VARCHAR(200) NULL
GO

/****** Object:  StoredProcedure [dbo].[dDSelectDisturbancesForMeterIDByDateRange]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[dDSelectDisturbancesForMeterIDByDateRange]
     
    @EventDateFrom as DateTime, 
    @EventDateTo as DateTime, 
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',');

DECLARE @counter INT = 0
DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
DECLARE @endDate DATE = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))
DECLARE @numberOfDays INT = DATEDIFF(DAY, @startDate, @endDate)

DECLARE @eventDate DATE = @startDate

CREATE TABLE #temp(Date DATE)

WHILE (@counter < @numberOfDays)
BEGIN
    INSERT INTO #temp VALUES(@eventDate)
    SET @eventDate = DATEADD(DAY, 1, @eventDate)
    SET @counter = @counter + 1
END

SELECT Date AS thedate, [5], [4], [3], [2], [1], [0]
FROM
(
    SELECT
        #temp.Date,
        SeverityCodes.SeverityCode AS SeverityCode,
        COALESCE(DisturbanceCount, 0) AS DisturbanceCount
    FROM
        #temp CROSS JOIN
		( Select 5 AS SeverityCode UNION 
		  SELECT 4 AS SeverityCode UNION 
		  SELECT 3 AS SeverityCode UNION 
		  SELECT 2 AS SeverityCode UNION 
		  SELECT 1 AS SeverityCode UNION 
		  SELECT 0 AS SeverityCode
		) AS SeverityCodes LEFT OUTER JOIN
        (
            SELECT
                CAST(Disturbance.StartTime AS DATE) AS DisturbanceDate,
                SeverityCode,
                COUNT(*) AS DisturbanceCount
            FROM
                (SELECT [DisturbanceID],Max([SeverityCode]) as SeverityCode
				  FROM [DisturbanceSeverity]
				  WHERE DisturbanceSeverity.VoltageEnvelopeID = (Select Value FROM Setting WHERE Name = 'DefaultDisturbanceEnvelope')
				  Group By DisturbanceID) as DisturbanceSeverity JOIN
				Disturbance ON Disturbance.ID = DisturbanceSeverity.DisturbanceID JOIN
				Event ON Event.ID = Disturbance.EventID JOIN
                Phase ON Disturbance.PhaseID = Phase.ID
			WHERE
                (
                    @MeterID = '0' OR
                    MeterID IN (SELECT * FROM @MeterIDs)
                ) AND
                MeterID IN (SELECT * FROM authMeters(@username)) AND
                Phase.Name = 'Worst' AND
                Disturbance.StartTime BETWEEN @startDate AND @endDate AND
                Disturbance.StartTime <> @endDate
            GROUP BY CAST(Disturbance.StartTime AS DATE), SeverityCode
        ) AS Disturbances ON #temp.Date = Disturbances.DisturbanceDate AND Disturbances.SeverityCode = SeverityCodes.SeverityCode
) AS DisturbanceDate
PIVOT
(
    SUM(DisturbanceDate.DisturbanceCount)
    FOR DisturbanceDate.SeverityCode IN ([5], [4], [3], [2], [1], [0])
) as pvt
ORDER BY Date

DROP TABLE #temp

END

GO
/****** Object:  StoredProcedure [dbo].[GetEventEmailRecipients]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[GetEventEmailRecipients]
(
    @eventID INT
)
AS BEGIN
    DECLARE @lineID INT
    DECLARE @startTime DATETIME2
    DECLARE @endTime DATETIME2
    DECLARE @timeTolerance FLOAT

    SELECT
        @lineID = LineID,
        @startTime = StartTime,
        @endTime = EndTime,
        @timeTolerance = COALESCE(Value, 0.5)
    FROM
        Event LEFT OUTER JOIN
        Setting ON Setting.Name = 'TimeTolerance'
    WHERE Event.ID = @eventID

    ; WITH cte AS
    (
        SELECT
            EmailGroupID,
            UserAccountID
        FROM EmailGroupUserAccount
        UNION
        SELECT
            EmailGroupSecurityGroup.EmailGroupID,
            UserAccount.ID
        FROM
            EmailGroupSecurityGroup JOIN
            SecurityGroupUserAccount ON EmailGroupSecurityGroup.SecurityGroupID = SecurityGroupUserAccount.SecurityGroupID JOIN
            UserAccount on SecurityGroupUserAccount.UserAccountID = UserAccount.ID
    )
    SELECT DISTINCT
        EmailGroupUserAccount.UserAccountID,
        EmailType.XSLTemplateID AS TemplateID
    FROM
        GetSystemEventIDs(@startTime, @endTime, @timeTolerance) SystemEventID JOIN
        Event ON
            SystemEventID.EventID = Event.ID AND
            Event.LineID = @lineID JOIN
        EventType ON Event.EventTypeID = EventType.ID JOIN
        Meter ON Event.MeterID = Meter.ID LEFT OUTER JOIN
        MeterMeterGroup ON MeterMeterGroup.MeterID = Meter.ID LEFT OUTER JOIN
        LineLineGroup ON LineLineGroup.LineID = Event.LineID LEFT OUTER JOIN
        EmailGroupMeterGroup ON MeterMeterGroup.MeterGroupID = EmailGroupMeterGroup.MeterGroupID LEFT OUTER JOIN
        EmailGroupLineGroup ON LineLineGroup.LineGroupID = EmailGroupLineGroup.LineGroupID JOIN
        EmailGroup ON
            EmailGroupMeterGroup.EmailGroupID = EmailGroup.ID OR
            EmailGroupLineGroup.EmailGroupID = EmailGroup.ID JOIN
        cte EmailGroupUserAccount ON EmailGroupUserAccount.EmailGroupID = EmailGroup.ID JOIN
        EmailGroupType ON EmailGroupType.EmailGroupID = EmailGroup.ID JOIN
        EmailType ON EmailGroupType.EmailTypeID = EmailType.ID JOIN
        EmailCategory ON
            EmailType.EmailCategoryID = EmailCategory.ID AND
            EmailCategory.Name = 'Event'
    WHERE
        (
            NOT EXISTS
            (
                SELECT *
                FROM FaultEmailCriterion
                WHERE FaultEmailCriterion.EmailGroupID = EmailGroup.ID
            )
            AND NOT EXISTS
            (
                SELECT *
                FROM DisturbanceEmailCriterion
                WHERE DisturbanceEmailCriterion.EmailGroupID = EmailGroup.ID
            )
			AND NOT EXISTS
			(
				SELECT *
				FROM BreakerEmailCriterion
				WHERE BreakerEmailCriterion.EmailGroupID = EmailGroup.ID
			)
        )
        OR
        (
            EventType.Name = 'Fault' AND
            EXISTS
            (
                SELECT *
                FROM FaultEmailCriterion
                WHERE FaultEmailCriterion.EmailGroupID = EmailGroup.ID
            )
        )
        OR
        (
            EventType.Name = 'RecloseIntoFault' AND
            EXISTS
            (
                SELECT *
                FROM FaultEmailCriterion
                WHERE
                    FaultEmailCriterion.EmailGroupID = EmailGroup.ID AND
                    FaultEmailCriterion.EmailOnReclose <> 0
            )
        )
        OR EXISTS
        (
            SELECT *
            FROM
                Disturbance JOIN
                DisturbanceSeverity ON DisturbanceSeverity.DisturbanceID = Disturbance.ID JOIN
                DisturbanceEmailCriterion ON DisturbanceSeverity.SeverityCode = DisturbanceEmailCriterion.SeverityCode
            WHERE
                Disturbance.EventID = Event.ID AND
                DisturbanceEmailCriterion.EmailGroupID = EmailGroup.ID
        )
        OR EXISTS
        (
            SELECT *
            FROM
				BreakerOperation JOIN
				BreakerOperationType ON BreakerOperation.BreakerOperationTypeID = BreakerOperationType.ID CROSS JOIN
				BreakerEmailCriterion
            WHERE
				BreakerOperation.EventID = Event.ID AND
				BreakerOperationType.Name = 'Late' AND
				BreakerEmailCriterion.EmailGroupID = EmailGroup.ID
        )
END

GO
/****** Object:  StoredProcedure [dbo].[GetGlobalEventsForGrafana]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- [GetGlobalEventsForGrafana] '2014-01-01T05:00:00.000Z', '2015-01-01T04:59:59.999Z', 6, 'h', 'EventCount'
-- =============================================
CREATE PROCEDURE [dbo].[GetGlobalEventsForGrafana]
    -- Add the parameters for the stored procedure here
    @startDate as DateTime, 
    @endDate as DateTime, 
    @step as int,
	@stepUnit nvarchar(10),
	@table nvarchar(20)
AS
BEGIN
SET NOCOUNT ON

DECLARE @stepWord as nvarchar(20) = CASE 
	WHEN @stepUnit = 'ms' THEN 'millisecond'
	WHEN @stepUnit = 's' THEN 'second'
	WHEN @stepUnit = 'm' THEN 'minute' 
	WHEN @stepUnit = 'h' THEN 'hour'  
	WHEN @stepUnit = 'd' THEN 'day'  
	ELSE 'second'
END

DECLARE @tableWord as nvarchar(20) = CASE 
	WHEN @table = 'Event' THEN 'Event'
	WHEN @table = 'Fault' THEN 'FaultSummary'
	WHEN @table = 'Alarm' THEN 'ChannelAlarmSummary' 
	ELSE 'Event'
END

DECLARE @dateWord as nvarchar(20)= CASE 
	WHEN @table = 'EventCount' THEN 'StartTime'
	WHEN @table = 'FaultCount' THEN 'Inception'
	WHEN @table = 'AlarmCount' THEN 'Date' 
	ELSE 'Event'
END


DECLARE @sql as nvarchar(max) = 
'   CREATE Table #temp ([Date] Datetime, [Count] int)																				
	DECLARE @dateDiff as int = DATEDIFF(' + @stepWord + ', @startDate, @endDate)
	DECLARE @dateIndex as DateTime = @startDate

	WHILE @dateIndex < @endDate
	BEGIN
  	INSERT INTO #temp VALUES (@dateIndex,((SELECT COUNT(*)  
  											FROM ' + @tableWord + ' 
  											WHERE ' + @dateWord + ' BETWEEN @dateIndex AND DATEADD(' + @stepWord + ',@step,@dateIndex)
  											)))
  	SET @dateIndex = DATEADD(' + @stepWord + ',@step,@dateIndex)
	END
  
	select TOP 1475 * from #temp
  
  
	drop table #temp  '

  exec sp_executesql @sql, N'@step int, @startDate DATETIME, @endDate DATETIME ', @step = @step, @startDate = @startDate, @endDate = @endDate

END


GO
/****** Object:  StoredProcedure [dbo].[GetGlobalEventsForGrafanaByMeterID]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- [GetGlobalEventsForGrafanaByMeterID] '2014-01-01T05:00:00.000Z', '2015-01-01T04:59:59.999Z', 6, 'h', 'EventCount','1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339'

-- =============================================
CREATE PROCEDURE [dbo].[GetGlobalEventsForGrafanaByMeterID]
    -- Add the parameters for the stored procedure here
    @startDate as DateTime, 
    @endDate as DateTime, 
    @step as int,
	@stepUnit nvarchar(10),
	@table nvarchar(20),
	@meterID as nvarchar(max)
AS
BEGIN
SET NOCOUNT ON

DECLARE @stepWord as nvarchar(20) = CASE 
	WHEN @stepUnit = 'ms' THEN 'millisecond'
	WHEN @stepUnit = 's' THEN 'second'
	WHEN @stepUnit = 'm' THEN 'minute' 
	WHEN @stepUnit = 'h' THEN 'hour'  
	WHEN @stepUnit = 'd' THEN 'day'  
	ELSE 'second'
END

DECLARE @tableWord as nvarchar(20) = CASE 
	WHEN @table = 'Event' THEN 'Event'
	WHEN @table = 'Fault' THEN 'FaultSummary'
	WHEN @table = 'Alarm' THEN 'ChannelAlarmSummary' 
	ELSE 'Event'
END

DECLARE @dateWord as nvarchar(20)= CASE 
	WHEN @table = 'EventCount' THEN 'StartTime'
	WHEN @table = 'FaultCount' THEN 'Inception'
	WHEN @table = 'AlarmCount' THEN 'Date' 
	ELSE 'StartTime'
END

DECLARE @MeterIDWord as nvarchar(MAX)= CASE 
	WHEN @table = 'EventCount' THEN N'MeterID IN (SELECT * FROM String_To_Int_Table(''' + @meterID + ''','',''))'
	WHEN @table = 'FaultCount' THEN N'EventID IN (Select ID FROM Event WHERE MeterID IN (SELECT * FROM String_To_Int_Table(' + @meterID + ','','')))'
	WHEN @table = 'AlarmCount' THEN N'ChannelID IN (SELECT ID FROM Channel WHERE MeterID IN (SELECT * FROM String_To_Int_Table(' + @meterID + ','','')))'
	ELSE N'MeterID IN (SELECT * FROM String_To_Int_Table(' + @meterID + ','',''))'
END


DECLARE @sql as nvarchar(max) = 
N'   CREATE Table #temp ([Date] Datetime, [Count] int)																				
	DECLARE @dateDiff as int = DATEDIFF(' + @stepWord + ', @startDate, @endDate)
	DECLARE @dateIndex as DateTime = @startDate

	WHILE @dateIndex < @endDate
	BEGIN
  	INSERT INTO #temp VALUES (@dateIndex,((SELECT COUNT(*)  
  											FROM ' + @tableWord + ' 
  											WHERE ' + @dateWord + ' BETWEEN @dateIndex AND DATEADD(' + @stepWord + ',@step,@dateIndex) AND '+ @MeterIDWord + '
  											)))
  	SET @dateIndex = DATEADD(' + @stepWord + ',@step,@dateIndex)
	END
  
	select TOP 1475 * from #temp
  
  
	drop table #temp  '
print @sql
--  exec sp_executesql @sql, N'@step int, @startDate DATETIME, @endDate DATETIME ', @step = @step, @startDate = @startDate, @endDate = @endDate

END


GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIds]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIds]
    @EventID as INT
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @currentTime DATETIME2,
            @meterID INT,
            @lineID INT

    SELECT @currentTime = StartTime, @meterID = MeterID, @lineID = LineID
    FROM Event
    WHERE ID = @EventID

    SELECT evt2.ID as previd, evt3.ID as nextid
    FROM Event evt1 LEFT OUTER JOIN 
         Event evt2 ON evt2.StartTime = (SELECT MAX(StartTime)
         FROM Event
         WHERE StartTime < @currentTime AND MeterID = @meterID AND LineID = @lineID) AND evt2.MeterID = @meterID AND evt2.LineID = @lineID 
         LEFT OUTER JOIN 
         Event evt3 ON evt3.StartTime = (SELECT MIN(StartTime)
         FROM Event
         WHERE StartTime > @currentTime AND MeterID = @meterID AND LineID = @lineID) 
         AND evt3.MeterID = @meterID AND evt3.LineID = @lineID
    WHERE evt1.ID = @EventID
END

GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIdsForLine]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIdsForLine]
    @EventID as INT
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startTime DATETIME2
    DECLARE @lineID INT
    DECLARE @prevID INT
    DECLARE @nextID INT

    SELECT
        @startTime = Event.StartTime,
        @lineID = Event.LineID
    FROM Event
    WHERE Event.ID = @EventID

    SELECT @prevID = COALESCE
    (
        (
            SELECT MAX(Event.ID)
            FROM Event
            WHERE
                Event.ID < @EventID AND
                StartTime = @startTime AND
                LineID = @lineID
        ),
        (
            SELECT MAX(Event.ID)
            FROM Event
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime < @startTime) AND
                LineID = @lineID
        )
    )

    SELECT @nextID = COALESCE
    (
        (
            SELECT MIN(Event.ID)
            FROM Event
            WHERE
                Event.ID > @EventID AND
                StartTime = @startTime AND
                LineID = @lineID
        ),
        (
            SELECT MIN(Event.ID)
            FROM Event
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime > @startTime) AND
                LineID = @lineID
        )
    )

    SELECT
        @prevID AS previd,
        @nextID AS nextid
END

GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIdsForMeter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIdsForMeter]
    @EventID as INT
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startTime DATETIME2
    DECLARE @meterID INT
    DECLARE @prevID INT
    DECLARE @nextID INT

    SELECT
        @startTime = Event.StartTime,
        @meterID = Event.MeterID
    FROM Event
    WHERE Event.ID = @EventID

    SELECT @prevID = COALESCE
    (
        (
            SELECT MAX(Event.ID)
            FROM Event
            WHERE
                Event.ID < @EventID AND
                StartTime = @startTime AND
                MeterID = @meterID
        ),
        (
            SELECT MAX(Event.ID)
            FROM Event
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime < @startTime) AND
                MeterID = @meterID
        )
    )

    SELECT @nextID = COALESCE
    (
        (
            SELECT MIN(Event.ID)
            FROM Event
            WHERE
                Event.ID > @EventID AND
                StartTime = @startTime AND
                MeterID = @meterID
        ),
        (
            SELECT MIN(Event.ID)
            FROM Event
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime > @startTime) AND
                MeterID = @meterID
        )
    )

    SELECT
        @prevID AS previd,
        @nextID AS nextid
END

GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIdsForMeterLocation]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIdsForMeterLocation]
    @EventID as INT
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startTime DATETIME2
    DECLARE @meterLocationID INT
    DECLARE @prevID INT
    DECLARE @nextID INT

    SELECT
        @startTime = Event.StartTime,
        @meterLocationID = Meter.MeterLocationID
    FROM
        Event JOIN
        Meter ON Event.MeterID = Meter.ID
    WHERE Event.ID = @EventID

    SELECT @prevID = COALESCE
    (
        (
            SELECT MAX(Event.ID)
            FROM
                Event JOIN
                Meter ON Event.MeterID = Meter.ID
            WHERE
                Event.ID < @EventID AND
                StartTime = @startTime AND
                MeterLocationID = @meterLocationID
        ),
        (
            SELECT MAX(Event.ID)
            FROM
                Event JOIN
                Meter ON Event.MeterID = Meter.ID
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime < @startTime) AND
                MeterLocationID = @meterLocationID
        )
    )

    SELECT @nextID = COALESCE
    (
        (
            SELECT MIN(Event.ID)
            FROM
                Event JOIN
                Meter ON Event.MeterID = Meter.ID
            WHERE
                Event.ID > @EventID AND
                StartTime = @startTime AND
                MeterLocationID = @meterLocationID
        ),
        (
            SELECT MIN(Event.ID)
            FROM
                Event JOIN
                Meter ON Event.MeterID = Meter.ID
            WHERE
                StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime > @startTime) AND
                MeterLocationID = @meterLocationID
        )
    )

    SELECT
        @prevID AS previd,
        @nextID AS nextid
END

GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIdsForSystem]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIdsForSystem]
    @EventID as INT
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startTime DATETIME2
    DECLARE @prevID INT
    DECLARE @nextID INT

    SELECT @startTime = StartTime
    FROM Event
    WHERE ID = @EventID

    SELECT @prevID = COALESCE
    (
        (SELECT MAX(ID) FROM Event WHERE ID < @EventID AND StartTime = @startTime),
        (SELECT MAX(ID) FROM Event WHERE StartTime = (SELECT MAX(StartTime) FROM Event WHERE StartTime < @startTime))
    )

    SELECT @nextID = COALESCE
    (
        (SELECT MIN(ID) FROM Event WHERE ID > @EventID AND StartTime = @startTime),
        (SELECT MIN(ID) FROM Event WHERE StartTime = (SELECT MIN(StartTime) FROM Event WHERE StartTime > @startTime))
    )

    SELECT
        @prevID AS previd,
        @nextID AS nextid
END

GO
/****** Object:  StoredProcedure [dbo].[GetPreviousAndNextEventIdsNonMeter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[GetPreviousAndNextEventIdsNonMeter]
    @EventID as INT
AS
BEGIN
	SET NOCOUNT ON;

	DECLARE @currentTime DATETIME2

	SELECT @currentTime = StartTime
	FROM Event
	WHERE ID = @EventID

	SELECT evt2.ID as previd, evt3.ID as nextid
	FROM Event evt1 LEFT OUTER JOIN 
		 Event evt2 ON evt2.StartTime = 
			 (SELECT MAX(StartTime)
			 FROM Event
			 WHERE StartTime < @currentTime ) LEFT OUTER JOIN 
		 Event evt3 ON evt3.StartTime = (SELECT MIN(StartTime)
			 FROM Event
			 WHERE StartTime > @currentTime )
	WHERE evt1.ID = @EventID
END

GO
/****** Object:  StoredProcedure [dbo].[GetSiteSummaries]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[GetSiteSummaries]
    -- Add the parameters for the stored procedure here
    @startDate as DateTime, 
    @endDate as DateTime, 
    @filterID as int,
	@Page int,
	@RecsPerPage int,
	@orderBy varchar(MAX),
	@filterString varchar(MAX)
AS
BEGIN
SET NOCOUNT ON


DECLARE @sql NVARCHAR(MAX)

SET @sql = '
DECLARE @Page int, @RecsPerPage int
SET @Page = ' + CAST(@Page as varchar) + '
SET @RecsPerPage = ' + CAST(@RecsPerPage as varchar) + '
-- Determine the first record and last record 
DECLARE @FirstRec int, @LastRec int
SELECT @FirstRec = (@Page - 1) * @RecsPerPage;
SELECT @LastRec = (@Page * @RecsPerPage + 1);
DECLARE @EventDateFrom DATE = CAST( '''+ CAST(@startDate as varchar(100)) +''' AS DATE)
DECLARE @EventDateTO DATE = CAST( '''+ CAST(@endDate as varchar(100)) +''' AS DATE)
DECLARE @filterID int = ' + CAST(@filterID as varchar(4)) + ';
WITH TempResult as
(
SELECT 
  '
  +
    ' Meter.Name AS MeterID, 
	   (SELECT SUM(100.0 * CAST(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints AS FLOAT) / CAST(NULLIF(ExpectedPoints, 0) AS FLOAT)) / DATEDIFF(day, @EventDateFrom, @EventDateTo) FROM MeterDataQualitySummary WHERE MeterID = Meter.ID AND MeterDataQualitySummary.Date BETWEEN @EventDateFrom AND @EventDateTo ) as Completeness,
	   (SELECT SUM(100.0 * CAST(GoodPoints AS FLOAT) / CAST(NULLIF(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints, 0) AS FLOAT)) / DATEDIFF(day, @EventDateFrom,  @EventDateTo) FROM MeterDataQualitySummary WHERE MeterID = Meter.ID AND MeterDataQualitySummary.Date BETWEEN @EventDateFrom AND @EventDateTo) as Correctness,
	   (SELECT COUNT(Event.ID) FROM Event WHERE MeterID = Meter.ID AND StartTime BETWEEN @EventDateFrom AND @EventDateTo AND EventTypeID IN (SELECT * FROM String_To_Int_Table((SELECT EventTypes FROM WorkbenchFilter Where ID = @filterID), '',''))) AS [Events],
       (SELECT COUNT(Disturbance.ID) FROM Disturbance JOIN Event ON Disturbance.EventID = Event.ID WHERE MeterID = Meter.ID AND Event.StartTime BETWEEN @EventDateTo AND @EventDateFrom) AS Disturbances, 
       (SELECT COUNT(ID) FROM FaultView WHERE MeterID = Meter.ID AND InceptionTime BETWEEN @EventDateFrom AND @EventDateTo AND RK = 1) AS Faults,
       (SELECT Max(Maximum) FROM DailyTrendingSummary WHERE ChannelID IN (SELECT ID FROM Channel WHERE MeterID = Meter.ID AND MeasurementTypeID = 2) AND Date BETWEEN @EventDateFrom AND @EventDateTo) AS MaxCurrent,
       (SELECT Min(Minimum) FROM DailyTrendingSummary WHERE ChannelID IN (SELECT ID FROM Channel WHERE MeterID = Meter.ID AND MeasurementTypeID = 1) AND Date BETWEEN @EventDateFrom AND @EventDateTo) AS MinVoltage 
FROM Meter 
WHERE Meter.ID IN (Select * FROM String_To_Int_Table((Select Meters FROM WorkbenchFilter WHERE ID = @filterID), '','')) AND
	  Meter.Name LIKE ''%'+@filterString+'%''
), 
TempResult2 AS
(
	SELECT ROW_NUMBER() OVER(ORDER BY ' + @orderBy + ') as RowNum, * FROM TempResult
)
SELECT top (@LastRec-1) *
FROM TempResult2
WHERE RowNum > @FirstRec 
AND RowNum < @LastRec
'
print @sql
EXEC sp_executesql @sql
-- Turn NOCOUNT back OFF
SET NOCOUNT OFF
END
GO
/****** Object:  StoredProcedure [dbo].[InsertIntoAuditLog]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[InsertIntoAuditLog] (@tableName VARCHAR(128), @primaryKeyColumn VARCHAR(128), @deleted BIT = '0', @inserted BIT = '0') AS
BEGIN

    DECLARE @columnName varchar(100)
    DECLARE @cursorColumnNames CURSOR

    SET @cursorColumnNames = CURSOR FOR
    SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = @tableName AND TABLE_CATALOG = db_name()

    OPEN @cursorColumnNames

    FETCH NEXT FROM @cursorColumnNames INTO @columnName
    WHILE @@FETCH_STATUS = 0
    BEGIN

        DECLARE @sql VARCHAR(MAX)

        IF @deleted = '0' AND @inserted = '0'
        BEGIN
            SET @sql = 'DECLARE @oldVal NVARCHAR(MAX) ' +
                    'DECLARE @newVal NVARCHAR(MAX) ' +
                    'SELECT @oldVal = CONVERT(NVARCHAR(MAX), #deleted.' + @columnName + '), @newVal = CONVERT(NVARCHAR(MAX), #inserted.' + @columnName + ') FROM #deleted, #inserted ' +
                    'IF @oldVal <> @newVal BEGIN ' +
                    'INSERT INTO AuditLog (TableName, PrimaryKeyColumn, PrimaryKeyValue, ColumnName, OriginalValue, NewValue, Deleted, UpdatedBy) ' +
                    'SELECT ''' + @tableName + ''', ''' + @primaryKeyColumn + ''', CONVERT(NVARCHAR(MAX), #inserted.' + @primaryKeyColumn + '), ''' + @columnName + ''', ' +
                    'CONVERT(NVARCHAR(MAX), #deleted.' + @columnName + '), CONVERT(NVARCHAR(MAX), #inserted.' + @columnName + '), ''0'', #inserted.UpdatedBy ' +
                    'FROM #inserted JOIN #deleted ON #inserted.' + @primaryKeyColumn + ' = #deleted.' + @primaryKeyColumn + ' ' +
                    'END'

            EXECUTE (@sql)
        END

        FETCH NEXT FROM @cursorColumnNames INTO @columnName
    END

    CLOSE @cursorColumnNames
    DEALLOCATE @cursorColumnNames

END

GO
/****** Object:  StoredProcedure [dbo].[pivotedSelectFaultsForMeterIDByDateRange]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[pivotedSelectFaultsForMeterIDByDateRange]
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    declare  @MeterIDs TABLE (ID int);

    INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    declare @counter int = 0
    declare @EventDate as DateTime
    declare @NumberOfDays as INT

    set @NumberOfDays = DateDiff ( day  , @EventDateFrom , @EventDateTo )

    set @EventDate = @EventDateFrom

    PRINT @NumberOfDays
    PRINT @EventDate

    CREATE TABLE #temp(Date DATE)

    WHILE (@counter <= @numberOfDays)
    BEGIN
        INSERT INTO #temp VALUES(@eventDate)
        SET @eventDate = DATEADD(DAY, 1, @eventDate)
        SET @counter = @counter + 1
    END

	SELECT thedate, [500], [300], [230], [135], [115], [69], [46], [0]
	FROM
	(
    SELECT
        #temp.Date AS thedate,
        COALESCE(Event.FaultCount, 0) AS thecount,
        Line.VoltageKV AS theclass
    FROM
        #temp CROSS JOIN
        (
            SELECT DISTINCT VoltageKV
            FROM
                Line JOIN
                Channel ON Channel.LineID = Line.ID JOIN
                Meter ON Channel.MeterID = Meter.ID
            WHERE Meter.ID IN (SELECT * FROM authMeters(@username))
        ) Line LEFT OUTER JOIN
        (
            SELECT
                CAST(Event.StartTime AS Date) AS Date,
                Line.VoltageKV,
                COUNT(*) AS FaultCount
            FROM
                Event JOIN
                EventType ON Event.EventTypeID = EventType.ID JOIN
                Line ON Event.LineID = Line.ID
            WHERE
                EventType.Name = 'Fault' AND
                Event.MeterID IN (SELECT * FROM @MeterIDs)
            GROUP BY
                CAST(Event.StartTime AS Date),
                Line.VoltageKV
        ) Event ON Event.Date = #temp.Date AND Event.VoltageKV = Line.VoltageKV
		) as ptable
		PIVOT
		(
		SUM(thecount)
		FOR theclass IN ([500], [300], [230], [135], [115], [69], [46], [0])
		) as pvt
		ORDER BY thedate
END

GO
/****** Object:  StoredProcedure [dbo].[selectAlarmDataByChannelByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 2, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectAlarmDataByChannelByDate] '05/28/2008', '05/29/2008', 8026
-- =============================================
CREATE PROCEDURE [dbo].[selectAlarmDataByChannelByDate]
    @StartDate DateTime2,
    @EndDate DateTime2,
    @ChannelID int
AS
BEGIN
    SET NOCOUNT ON;

    -- Trending Data
    WITH TrendingData AS
    (
        SELECT
           *
        FROM
            GetTypedTrendingData(@StartDate, @EndDate, @ChannelID, default) AS TrendingData
    )
    SELECT
        *
    FROM
        TrendingData
    WHERE
        TrendingData.ChannelID = @ChannelID
    ORDER BY TrendingData.Time
END

GO
/****** Object:  StoredProcedure [dbo].[selectDisturbancesDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectDisturbancesDetailsByDate '07/19/2006', '07/05/2016', 'External'
-- selectSitesDisturbancesDetailsByDate '07/19/2014', '0','External'
-- =============================================
CREATE PROCEDURE [dbo].[selectDisturbancesDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @username as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID AS themeterid,
        Meter.Name AS thesite,
        MeterLocation.Latitude AS latitude,
        MeterLocation.Longitude AS longitude,
        COALESCE(Disturbance_Count, 0) AS Disturbance_Count,
        COALESCE([5], 0) AS [5],
        COALESCE([4], 0) AS [4],
        COALESCE([3], 0) AS [3],
        COALESCE([2], 0) AS [2],
        COALESCE([1], 0) AS [1],
        COALESCE([0], 0) AS [0]
    FROM
        Meter JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
        (
            SELECT
                MeterID,
                6*[5] + 5*[4] + 4*[3] + 3*[2] + 2*[1] + 1*[0] AS Disturbance_Count,
                [5],
                [4],
                [3],
                [2],
                [1],
                [0]
            FROM
            (
                SELECT
                    Event.MeterID,
                    DisturbanceSeverity.SeverityCode
                FROM
                    DisturbanceSeverity JOIN
                    Disturbance ON DisturbanceSeverity.DisturbanceID = Disturbance.ID JOIN
                    Event ON Disturbance.EventID = Event.ID
                WHERE CAST(Disturbance.StartTime AS DATE) BETWEEN @startDate AND @endDate
            ) AS MeterSeverityCode
            PIVOT
            (
                COUNT(SeverityCode)
                FOR SeverityCode IN ([5], [4], [3], [2], [1], [0])
            ) AS PivotTable
        ) AS SeverityCount ON SeverityCount.MeterID = Meter.ID
    WHERE Meter.ID IN (SELECT * FROM authMeters(@username))
END

GO
/****** Object:  StoredProcedure [dbo].[selectDisturbancesForMeterIDByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectDisturbancesForMeterIDByDate '01/10/2013', '05/10/2015', '0'
-- selectDisturbancesForMeterIDByDate '03/05/2007', '03/06/2015', '13,17,46,40,6,52,15,16,28,57,19,55,53,12,58,54,8,59,18,20,9,11,21,1,41,39,23,51,14,45,47,2,50,56,30,42,32,10,22,29,48,24,43,34,4,37,26,36,25,31,44,49,3,7,27,35,33,38,5,', 'External'
-- =============================================
CREATE PROCEDURE [dbo].[selectDisturbancesForMeterIDByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',');

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)
DECLARE @voltageEnvelope varchar(max) = (SELECT TOP 1 Value FROM Setting WHERE Name = 'DefaultVoltageEnvelope')
SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp (thesiteid int, thesitename varchar(100))

INSERT INTO #temp Select [dbo].[Meter].[ID], [dbo].[Meter].[Name] from [dbo].[Meter] where Meter.ID in (Select * from @MeterIDs)

SELECT thesiteid as siteid, thesitename as sitename, [5], [4], [3], [2], [1], [0]
FROM
(
    SELECT #temp.thesiteid, #temp.thesitename, SeverityCodes.SeverityCode AS SeverityCode, COALESCE(DisturbanceCount, 0) AS DisturbanceCount
    FROM
        #temp Cross JOIN
        ( Select 5 as SeverityCode UNION
          SELECT 4 as SeverityCode UNION
          SELECT 3 as SeverityCode UNION
          SELECT 2 as SeverityCode UNION
          SELECT 1 as SeverityCode UNION
          SELECT 0 as SeverityCode
        ) AS SeverityCodes LEFT OUTER JOIN
        (
            SELECT MeterID, SeverityCode, COUNT(*) AS DisturbanceCount
            FROM DisturbanceSeverity JOIN
                 Disturbance ON Disturbance.ID = DisturbanceSeverity.DisturbanceID Join
                 Event ON Event.ID = Disturbance.EventID JOIN
				 VoltageEnvelope ON VoltageEnvelope.ID = DisturbanceSeverity.VoltageEnvelopeID
            Where ( (CAST( Event.StartTime as Date) between @EventDateFrom and @EventDateTo))
            and MeterID in (select * from authMeters(@username))
            and Disturbance.PhaseID = (SELECT ID FROM Phase WHERE Name = 'Worst')
			and VoltageEnvelope.Name = COALESCE(@voltageEnvelope, 'ITIC')
            GROUP BY SeverityCode, MeterID
        ) AS Disturbances ON #temp.thesiteid = Disturbances.MeterID AND Disturbances.SeverityCode = SeverityCodes.SeverityCode
) AS DisturbanceData
PIVOT
(
    SUM(DisturbanceData.DisturbanceCount)
    FOR DisturbanceData.SeverityCode IN ([5], [4], [3], [2], [1], [0])
) as pvt
ORDER BY sitename asc

DROP TABLE #temp

END

GO
/****** Object:  StoredProcedure [dbo].[selectDisturbancesForMeterIDByDateRange]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectDisturbancesForMeterIDByDateRange '01/10/2013', '05/10/2015', '0'
-- selectDisturbancesForMeterIDByDateRange '03/05/2015', '03/06/2015', '0', 'External'
-- =============================================
CREATE PROCEDURE [dbo].[selectDisturbancesForMeterIDByDateRange]

    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

DECLARE @dateStatement NVARCHAR(200) = N'CAST(Disturbance.StartTime AS Date)'
DECLARE @groupByStatement NVARCHAR(200) = N'CAST(Disturbance.StartTime AS Date)'

IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
    SET @dateStatement = N'DateAdd(HOUR,DatePart(HOUR,Disturbance.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(HOUR, Disturbance.StartTime), DateAdd(HOUR,DatePart(HOUR,Disturbance.StartTime), @EventDateFrom)'
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
    SET @dateStatement = N'DateAdd(MINUTE,DatePart(MINUTE,Disturbance.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(MINUTE, Disturbance.StartTime), DateAdd(MINUTE,DatePart(MINUTE,Disturbance.StartTime), @EventDateFrom)'
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
    SET @dateStatement = N'DateAdd(SECOND,DatePart(SECOND,Disturbance.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(SECOND, Disturbance.StartTime), DateAdd(SECOND,DatePart(SECOND,Disturbance.StartTime), @EventDateFrom)'
END

DECLARE @voltageEnvelope varchar(max) = (SELECT TOP 1 Value FROM Setting WHERE Name = 'DefaultVoltageEnvelope')


DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

create table #TEMP (Name varchar(max))
insert into #TEMP SELECT SeverityCode FROM (Select Distinct SeverityCode FROM DisturbanceSeverity) as t

SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(Name as varchar(5)), '') + '],'
FROM #TEMP WHERE Name != 0 ORDER BY Name desc
SET @PivotColumns = @PivotColumns + '[0]'

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(Name as varchar(5)), '0') + '], 0) AS [' + COALESCE(CAST(Name as varchar(5)), '') + '],'
FROM #TEMP WHERE Name != 0 ORDER BY Name desc
SET @ReturnColumns = @ReturnColumns + 'COALESCE([0],0) as [0]'

SET @SQLStatement =
N' 
DECLARE @user varchar(max) = @username
DECLARE @ids varchar(max) = @MeterID
DECLARE @start DateTime = @startDate
DECLARE @end DateTime = @endDate

SELECT DisturbanceDate as thedate, ' + @ReturnColumns + '
 FROM (																		 
	SELECT                                                                       
		' + @dateStatement + ' AS DisturbanceDate,                	 
		SeverityCode,															 
		COUNT(*) AS DisturbanceCount											 
	FROM																		 
		DisturbanceSeverity JOIN												 
		Disturbance ON Disturbance.ID = DisturbanceSeverity.DisturbanceID JOIN	 
		Event ON Event.ID = Disturbance.EventID JOIN							 
		Phase ON Disturbance.PhaseID = Phase.ID	JOIN
		VoltageEnvelope ON VoltageEnvelope.ID = DisturbanceSeverity.VoltageEnvelopeID								 
	WHERE																		 
		(																		 
			@MeterID = ''0'' OR													 
			MeterID IN (SELECT * FROM String_To_Int_Table(@ids, '',''))	     
		) AND																	 
		MeterID IN (SELECT * FROM authMeters(@user)) AND					 
		Phase.Name = ''Worst'' AND
		VoltageEnvelope.Name = COALESCE(@voltageEnvelope, ''ITIC'') AND										 
		Disturbance.StartTime BETWEEN @start AND @end AND				 
		Disturbance.StartTime <> @endDate									 
	GROUP BY ' + @groupByStatement + ', SeverityCode 					 
	) As DisturbanceDate														 
 PIVOT(
		SUM(DisturbanceDate.DisturbanceCount) 
		FOR DisturbanceDate.SeverityCode IN(' + @PivotColumns + ')
 ) as pvt
 ORDER BY DisturbanceDate '
print @sqlstatement
exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIMe, @endDate DATEtime, @EventDateFrom DATETIME, @voltageEnvelope VARCHAR(MAX)', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom, @voltageEnvelope = @voltageEnvelope

END

GO
/****** Object:  StoredProcedure [dbo].[selectExtensionsForMeterIDByDateRange]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- [selectExtensionsForMeterIDByDateRange] '11/02/2008', '11/10/2008', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- [selectExtensionsForMeterIDByDateRange] '11/06/2008', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- [selectExtensionsForMeterIDByDateRange] '11/06/2008 05:00 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- [selectExtensionsForMeterIDByDateRange] '11/06/2008 05:08 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- =============================================
CREATE PROCEDURE [dbo].[selectExtensionsForMeterIDByDateRange]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)

AS
BEGIN

    SET NOCOUNT ON;
    DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

DECLARE @dateStatement NVARCHAR(200) = N'CAST(StartTime AS Date)'
DECLARE @groupByStatement NVARCHAR(200) = N'CAST(StartTime AS Date)'

IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
    SET @dateStatement = N'DateAdd(HOUR,DatePart(HOUR,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(HOUR, StartTime), DateAdd(HOUR,DatePart(HOUR,StartTime), @EventDateFrom)'
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
    SET @dateStatement = N'DateAdd(MINUTE,DatePart(MINUTE,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(MINUTE, StartTime), DateAdd(MINUTE,DatePart(MINUTE,StartTime), @EventDateFrom)'
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
    SET @dateStatement = N'DateAdd(SECOND,DatePart(SECOND,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(SECOND, StartTime), DateAdd(SECOND,DatePart(SECOND,StartTime), @EventDateFrom)'
END



DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @MiddleStatment NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

SELECT @PivotColumns = @PivotColumns + '[' + t.ServiceName + '],'
FROM (Select ServiceName FROM EASExtension) AS t

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + t.ServiceName + '], 0) AS [' + t.ServiceName + '],'
FROM (Select ServiceName FROM EASExtension) AS t

SELECT @MiddleStatment = @MiddleStatment +  '
            SELECT '+@dateStatement+' as date,
                '''+ t.ServiceName + ''' as ServiceName,
                Count(*) as EventCount
            FROM    #temp
            WHERE   dbo.' + t.HasResultFunction + '(ID) != ''''
            GROUP BY '+ @dateStatement + ' UNION'

FROM (Select * FROM EASExtension) AS t

SELECT * INTO #temp
FROM EVENT
WHERE   StartTime Between @startDate AND @endDate AND
        MeterID in (select * from authMeters(@username)) AND
        MeterID IN (SELECT * FROM String_To_Int_Table( @MeterID,  ','))

CREATE INDEX tempIndex ON #temp (MeterID)

SET @SQLStatement =
'
SELECT Date as thedate, ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
FROM (
        SELECT * FROM (
        ' + SUBSTRING(@MiddleStatment,0, LEN(@MiddleStatment) - LEN('UNION')) + ' ) as innertable
       ) as ed
 PIVOT(
        SUM(ed.EventCount)
        FOR ed.ServiceName IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
 ) as pvt
 ORDER BY Date

 DROP TABLE #temp
 '

--print @startDate
--print @endDate
print @sqlstatement

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DATETIME ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom

END

GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsDisturbances]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectMeterLocationsDisturbances '10/06/2014', '10/06/2014', 'External'
-- selectMeterLocationsDisturbances '07/19/2014', '0','External'
-- =============================================
CREATE PROCEDURE [dbo].[selectMeterLocationsDisturbances]

    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @meterIds AS varchar(max),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom 
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))


IF @context = 'day'
BEGIN
	SET @endDate = DATEADD(DAY, 1, @startDate)
END

if @context = 'hour'
BEGIN
	SET @endDate = DATEADD(HOUR, 1, @startDate)
END

if @context = 'minute'
BEGIN
	SET @endDate = DATEADD(MINUTE, 1, @startDate)
END

if @context = 'second'
BEGIN
	SET @endDate = DATEADD(SECOND, 1, @startDate)
END


DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @CountColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''


create table #TEMP (Name varchar(max))
insert into #TEMP SELECT SeverityCode FROM (Select Distinct SeverityCode FROM DisturbanceSeverity) as t

SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(Name as varchar(5)), '') + '],' 
FROM #TEMP WHERE Name != 0 ORDER BY Name desc
SET @PivotColumns = @PivotColumns + '[0]'

SELECT @CountColumns = @CountColumns + 'COALESCE([' + COALESCE(CAST(Name as varchar(5)), '') + '], 0) + ' 
FROM #TEMP WHERE Name != 0 ORDER BY Name desc
SET @CountColumns = @CountColumns + 'COALESCE([0], 0) '


SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(Name as varchar(5)), '') + '], 0) AS [' + COALESCE(CAST(Name as varchar(5)), '') + '],' 
FROM #TEMP WHERE Name != 0ORDER BY Name desc
SET @ReturnColumns = @ReturnColumns + 'COALESCE([0], 0) as [0]'

DECLARE @voltageEnvelope varchar(max) = (SELECT TOP 1 Value FROM Setting WHERE Name = 'DefaultVoltageEnvelope')

DROP TABLE #TEMP

SET @SQLStatement = N'
DECLARE @user varchar(max) = @username
DECLARE @ids varchar(max) = @MeterIds
DECLARE @start DateTime = @startDate
DECLARE @end DateTime = @endDate

SELECT Meter.ID, 
		 Meter.Name,
		 MeterLocation.Longitude,
		 MeterLocation.Latitude,
		 ' + @CountColumns +' as Count,
		 ' + @ReturnColumns + '		  
FROM 
    Meter JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
	(
		SELECT MeterID, 
			   COUNT(*) AS EventCount, 
			   SeverityCode			   
		FROM Event JOIN
			 Disturbance ON Event.ID = Disturbance.EventID JOIN
			 Phase ON Phase.ID = Disturbance.PhaseID LEFT JOIN
			 DisturbanceSeverity ON Disturbance.ID = DisturbanceSeverity.DisturbanceID JOIN
			 VoltageEnvelope ON VoltageEnvelope.ID = DisturbanceSeverity.VoltageEnvelopeID	
        WHERE 
			 Phase.Name = ''Worst'' AND 
			 Disturbance.StartTime >= @start AND Disturbance.StartTime < @end AND
			 VoltageEnvelope.Name = COALESCE(@voltageEnvelope, ''ITIC'')										 
        GROUP BY Event.MeterID, SeverityCode 
       ) as ed 
	   PIVOT( 
	   		 SUM(ed.EventCount)
	   		 FOR ed.SeverityCode IN(' + @PivotColumns + ') 
	   ) as pvt On pvt.MeterID = meter.ID
	WHERE 
		Meter.ID in (select * from authMeters(@user)) AND 
		Meter.ID IN (SELECT * FROM String_To_Int_Table( @ids,  '',''))  

Order By Name '

print @SqlStatement
exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterIds nvarchar(MAX), @startDate DATETIME, @endDate DATETIME , @voltageEnvelope VARCHAR(MAX)', @username = @username, @MeterIds = @MeterIds, @startDate = @startDate, @endDate = @endDate, @voltageEnvelope = @voltageEnvelope

END

GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsExtensions]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Update date: <07/08/2016>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- [selectMeterLocationsExtensions] '11/02/2008', '11/10/2008', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- [selectMeterLocationsExtensions] '11/06/2008', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- [selectMeterLocationsExtensions] '11/06/2008 05:00 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- [selectMeterLocationsExtensions] '11/06/2008 05:08 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- [selectMeterLocationsExtensions] '11/06/2008 05:08:58 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'second'
-- [selectMeterLocationsExtensions] '07/18/2017 04:00 AM', '08/17/2017 04:00 AM', '1351,1352,1350', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'custom'
-- =============================================
CREATE PROCEDURE [dbo].[selectMeterLocationsExtensions]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max),
    @username as nvarchar(4000),
    @context as nvarchar(20)

AS
BEGIN

    SET NOCOUNT ON;
DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))


IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
END

if @context = 'second'
BEGIN
    SET @endDate = DATEADD(SECOND, 1, @startDate)
END


DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @CountColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''
DECLARE @MiddleStatment NVARCHAR(MAX) = N''

SELECT * INTO #temp
FROM EVENT
WHERE   StartTime Between @startDate AND @endDate AND
        MeterID in (select * from authMeters(@username)) AND
        MeterID IN (SELECT * FROM String_To_Int_Table( @meterIds,  ','))

CREATE INDEX tempIndex ON #temp (MeterID)

CREATE TABLE #easTable( MeterID int, ServiceName varchar(max), EventCount int);

SELECT @PivotColumns = @PivotColumns + '[' + t.ServiceName + '],'
FROM (Select ServiceName FROM EASExtension) AS t

SELECT @CountColumns = @CountColumns + 'COALESCE([' + t.ServiceName + '], 0) + '
FROM (Select ServiceName FROM EASExtension) AS t


SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + t.ServiceName + '], 0) AS [' + t.ServiceName + '],'
FROM (Select ServiceName FROM EASExtension) AS t

DECLARE @serviceName as varchar(max);
DECLARE @hasResultFunction as varchar(max);

DECLARE aCursor CURSOR FOR
SELECT ServiceName, HasResultFunction FROM EASExtension
OPEN aCursor;
FETCH NEXT FROM aCursor into @serviceName, @hasResultFunction;
WHILE @@FETCH_STATUS = 0
   BEGIN
    DECLARE @Sql nvarchar(max) = N'
            INSERT INTO #easTable
            SELECT MeterID,
                '''+ @serviceName + ''' as ServiceName,
                Count(*) as EventCount
            FROM    #temp
            WHERE   dbo.' + @hasResultFunction + '(ID) != ''''
            GROUP BY MeterID'
    exec sp_executesql @sql
    FETCH NEXT FROM aCursor into @serviceName, @hasResultFunction;
   END;
CLOSE aCursor;
DEALLOCATE aCursor;


SELECT @MiddleStatment = @MiddleStatment +  '
            SELECT MeterID,
                '''+ t.ServiceName + ''' as ServiceName,
                Count(*) as EventCount
            FROM    #temp
            WHERE   dbo.' + t.HasResultFunction + '(ID) != ''''
            GROUP BY MeterID UNION'

FROM (Select * FROM EASExtension) AS t

SET @SQLStatement =
'
SELECT Meter.ID,
         Meter.Name,
         MeterLocation.Longitude,
         MeterLocation.Latitude,
         ' + SUBSTRING(@CountColumns,0, LEN(@CountColumns)) +' as Count,
         ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
FROM
    Meter JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
    #easTable as ed
       PIVOT(
             SUM(ed.EventCount)
             FOR ed.ServiceName IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
       ) as pvt On pvt.MeterID = meter.ID
WHERE
    Meter.ID in (select * from authMeters(@username)) AND
    Meter.ID IN (SELECT * FROM String_To_Int_Table( @MeterIds,  '',''))

ORDER BY Meter.Name

DROP TABLE #temp
DROP TABLE #easTable
'
--print @startDate
--print @endDate
print @sqlstatement

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterIds nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DATETIME ', @username = @username, @MeterIds = @MeterIds, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom

END


GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsTrendingData]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
-- [selectMeterLocationsTrendingData] '07/04/2008','08/05/2008', 'Voltage RMS', 'external'
-- =============================================
CREATE PROCEDURE [dbo].[selectMeterLocationsTrendingData]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @colorScaleName VARCHAR(200),
    @meterIds AS varchar(max)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @thedatefrom AS DATE
    DECLARE @thedateto AS DATE

    SET @thedatefrom = CAST(@EventDateFrom AS DATE)
    SET @thedateto = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        Data.Minimum AS Minimum,
        Data.Maximum AS Maximum,
        Data.Average AS Average,
        MeterLocation.Longitude,
        MeterLocation.Latitude
    FROM
        Meter LEFT OUTER JOIN
        (
            SELECT
                ContourChannel.MeterID AS MID,
                MIN(Minimum/COALESCE(ContourChannel.PerUnitValue, 1)) AS Minimum,
                MAX(Maximum/COALESCE(ContourChannel.PerUnitValue, 1)) AS Maximum,
                AVG(Average/COALESCE(ContourChannel.PerUnitValue, 1)) AS Average
            FROM
                ContourChannel JOIN
                DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = ContourChannel.ChannelID
            WHERE Date >= @thedatefrom AND Date <= @thedateto AND ContourColorScaleName = @colorScaleName
            GROUP BY ContourChannel.MeterID
        ) AS Data ON Data.MID = Meter.ID JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
    ORDER BY Meter.Name
END

GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsTrendingDataCurrent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
--update meterlocation set Longitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + (-90))
--update meterlocation set Latitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + 30)

--[selectMeterLocationsTrendingDataCurrent] '08/19/2008','08/20/2008', 'external'

CREATE PROCEDURE [dbo].[selectMeterLocationsTrendingDataCurrent]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

        declare @thedatefrom as Date;
        declare @thedateto as Date;

        set @thedatefrom = CAST(@EventDateFrom as Date);
        set @thedateto = CAST(@EventDateTo as Date);

		SELECT
			Meter.ID,
			Meter.Name,
			Data.Minimum,
			Data.Maximum,
			Data.Average,
			MeterLocation.Longitude,
			MeterLocation.Latitude
		FROM
			Meter LEFT JOIN
			( SELECT Channel.MeterID as MID,
					 MIN(Minimum) as Minimum,
					 MAX(Maximum) as Maximum,
					 AVG(Average) as Average

			  FROM Channel JOIN 
				   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID
			  WHERE Channel.MeasurementTypeID = 2 AND Date >= @EventDateFrom AND Date <= @EventDateTo
			  GROUP BY Channel.MeterID

			) as Data ON Data.MID = Meter.ID JOIN
			MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
       WHERE [dbo].[Meter].[ID] in (SELECT * FROM authMeters(@username))
       ORDER BY Meter.Name
END


GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsTrendingDataPower]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
--update meterlocation set Longitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + (-90))
--update meterlocation set Latitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + 30)

--[selectMeterLocationsTrendingDataPower] '08/19/2008','08/20/2008', 'external'

CREATE PROCEDURE [dbo].[selectMeterLocationsTrendingDataPower]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

        declare @thedatefrom as Date;
        declare @thedateto as Date;

        set @thedatefrom = CAST(@EventDateFrom as Date);
        set @thedateto = CAST(@EventDateTo as Date);

		SELECT
			Meter.ID,
			Meter.Name,
			Data.Minimum,
			Data.Maximum,
			Data.Average,
			MeterLocation.Longitude,
			MeterLocation.Latitude,
			Data.MeasurementCharacteristic,
			Data.Phase
		FROM
			Meter LEFT JOIN
			( SELECT Channel.MeterID as MID,
					 MIN(Minimum) as Minimum,
					 MAX(Maximum) as Maximum,
					 AVG(Average) as Average,
					 MeasurementCharacteristic.Name as MeasurementCharacteristic,
					 Phase.Name as Phase
			  FROM Channel JOIN 
				   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID JOIN
				   MeasurementType ON MeasurementType.ID = Channel.MeasurementTypeID JOIN
				   MeasurementCharacteristic ON MeasurementCharacteristic.ID = Channel.MeasurementCharacteristicID JOIN
				   Phase ON Phase.ID = Channel.PhaseID
			  WHERE MeasurementType.Name = 'Power'  AND Date >= @EventDateFrom AND Date <= @EventDateTo
			  GROUP BY Channel.MeterID,MeasurementCharacteristic.Name, Phase.Name
			) as Data ON Data.MID = Meter.ID JOIN
			MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
       WHERE [dbo].[Meter].[ID] in (SELECT * FROM authMeters(@username))
       ORDER BY Meter.Name
END


GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsTrendingDataVoltage]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>

-- =============================================
--update meterlocation set Longitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + (-90))
--update meterlocation set Latitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + 30)

--[selectMeterLocationsTrendingDataVoltage] '07/04/2008','08/05/2008', 'external'

CREATE PROCEDURE [dbo].[selectMeterLocationsTrendingDataVoltage]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

        declare @thedatefrom as Date;
        declare @thedateto as Date;

        set @thedatefrom = CAST(@EventDateFrom as Date);
        set @thedateto = CAST(@EventDateTo as Date);

		SELECT
			Meter.ID,
			Meter.Name,
			Data.Minimum as Minimum,
			Data.Maximum as Maximum,
			Data.Average as Average,
			MeterLocation.Longitude,
			MeterLocation.Latitude
		FROM
			Meter LEFT JOIN
			( SELECT Channel.MeterID as MID,
					 MIN(Minimum/COALESCE(Channel.PerUnitValue,1)) as Minimum,
					 MAX(Maximum/COALESCE(Channel.PerUnitValue, 1)) as Maximum,
					 AVG(Average/COALESCE(Channel.PerUnitValue,1)) as Average

			  FROM Channel JOIN 
				   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID JOIN
				   MeasurementType ON MeasurementType.ID = Channel.MeasurementTypeID JOIN
				   MeasurementCharacteristic ON MeasurementCharacteristic.ID = Channel.MeasurementCharacteristicID JOIN
				   Phase ON Phase.ID = Channel.PhaseID
			  WHERE MeasurementType.Name = 'Voltage' AND MeasurementCharacteristic.Name = 'RMS' AND  Phase.Name IN ('AN', 'BN', 'CN', 'AB', 'BC', 'CA') AND Date >= @EventDateFrom AND Date <= @EventDateTo
			  GROUP BY Channel.MeterID

			) as Data ON Data.MID = Meter.ID JOIN
			MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
       WHERE [dbo].[Meter].[ID] in (SELECT * FROM authMeters(@username))
       ORDER BY Meter.Name

END


GO
/****** Object:  StoredProcedure [dbo].[selectMeterLocationsTrendingDataVoltageAnimation]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>

-- =============================================
--update meterlocation set Longitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + (-90))
--update meterlocation set Latitude = (select (cast(abs(checksum(NewId())) % 10000 as float) /1000) + 30)

--[selectMeterLocationsTrendingDataVoltageAnimation] '07/04/2008 00:00:00', '07/04/2008 23:45:00', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 15, 'external' 
--[selectMeterLocationsTrendingDataVoltageAnimation] '07/16/2008 00:00:00', '08/15/2008 23:45:00', '91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108', 15, 'external' 

CREATE PROCEDURE [dbo].[selectMeterLocationsTrendingDataVoltageAnimation]
       -- Add the parameters for the stored procedure here
    @EventDateFrom DateTime2,
	@EventDateTo DateTime2,
    @MeterID AS nvarchar(MAX),
	@StepSize AS int,
	@username AS nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;
	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @DateFrom DateTime2 = @EventDateFrom; 
	DECLARE  @DateTo DateTime2 = @EventDateTo;


-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

	DECLARE  @Counter INT = 0;
	DECLARE  @NumberOfIntervals INT = DATEDIFF(mi, @DateFrom, @DateTo)/@StepSize;
	DECLARE  @Date DateTime2 = @DateFrom;

	CREATE TABLE #temp(Date DATETIME2)

	WHILE (@counter <= @NumberOfIntervals)
	BEGIN
		INSERT INTO #temp VALUES(@Date)
		SET @Date = DATEADD(mi, @StepSize, @Date)
		SET @counter = @counter + 1
	END

	SELECT @ChannelID = COALESCE(@ChannelID + ',' + CAST(ID AS NVARCHAR(10)), CAST(ID AS NVARCHAR(10))) FROM Channel WHERE Channel.MeterID IN (SELECT * FROM @MeterIDs);

WITH TrendingDataPoint AS
(
    SELECT
        ChannelID,
        SeriesType,
        Time,
        Value
    FROM
        GetTrendingData(@DateFrom, @DateTo, @ChannelID, default) AS TrendingData JOIN
        (
            SELECT 0 AS ID, 'Minimum' AS SeriesType UNION
            SELECT 1 AS ID, 'Maximum' AS SeriesType UNION
            SELECT 2 AS ID, 'Average' AS SeriesType
        ) AS Series ON TrendingData.SeriesID = Series.ID
),
TrendingData AS
(
    SELECT
        ChannelID,
        Time,
        Maximum,
        Minimum,
        Average
    FROM TrendingDataPoint
    PIVOT
    (
        SUM(Value)
        FOR SeriesType IN (Maximum, Minimum, Average)
    ) AS TrendingData
),
MeterTable AS (
	SELECT
		ID,
		Date
	FROM @MeterIDs CROSS JOIN #temp
)

SELECT
	MeterTable.ID as ID,
	MeterTable.Date as Date,
	MIN([TrendingData].[Minimum]/COALESCE(ChannelTable.PerUnitValue,1)) as Minimum,
	MAX([TrendingData].[Maximum]/COALESCE(ChannelTable.PerUnitValue,1)) as Maximum,
	AVG([TrendingData].[Average]/COALESCE(ChannelTable.PerUnitValue,1)) as Average,
	MeterLocation.Latitude,
	MeterLocation.Longitude,
	Meter.Name
FROM 
	MeterTable LEFT JOIN(
		SELECT
			Channel.ID,
			Channel.MeterID,
			Channel.PerUnitValue, 
			CAST(60/Channel.SamplesPerHour AS INT) AS ChannelSampleRate
		FROM Channel JOIN
			 MeasurementType ON MeasurementType.ID = Channel.MeasurementTypeID JOIN
			 MeasurementCharacteristic ON MeasurementCharacteristic.ID = Channel.MeasurementCharacteristicID JOIN
			 Phase ON Phase.ID = Channel.PhaseID
		WHERE 
			MeasurementType.name = 'Voltage' AND MeasurementCharacteristic.Name = 'RMS' AND Phase.Name IN ('AN', 'BN', 'CN', 'AB', 'BC', 'CA') AND CHANNEL.SamplesPerHour <= 60
			) AS ChannelTable ON ChannelTable.MeterID = MeterTable.ID LEFT JOIN
	[TrendingData]  ON TrendingData.ChannelID = ChannelTable.ID AND TrendingData.Time = DATEADD(mi, ChannelTable.ChannelSampleRate*FLOOR(DATEPART(mi, MeterTable.Date)/ ChannelTable.ChannelSampleRate), DATEADD(mi, -DATEPART(mi, MeterTable.Date), MeterTable.Date))  JOIN
	Meter ON Meter.Id = MeterTable.ID JOIN
	MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
GROUP BY MeterTable.ID, MeterTable.Date, MeterLocation.Latitude, MeterLocation.Longitude, Meter.Name
ORDER BY MeterTable.Date, MeterTable.ID
	DROP TABLE #temp

END



GO
/****** Object:  StoredProcedure [dbo].[selectSiteLinesDisturbanceDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSiteLinesDisturbanceDetailsByDate '10/07/2014', '7'

-- =============================================
CREATE PROCEDURE [dbo].[selectSiteLinesDisturbanceDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @worstPhaseID INT = (SELECT ID FROM Phase WHERE Name = 'Worst')
	DECLARE @startDate DATETIME = @EventDate 
	DECLARE @endDate DATETIME


    IF @context = 'day'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(DAY, 1, @startDate)
    END

    if @context = 'hour'
    BEGIN
        SET @startDate = DATEADD(HOUR, DATEDIFF(HOUR, 0, @EventDate), 0)
        SET @endDate = DATEADD(HOUR, 1, @startDate)
    END

    if @context = 'minute'
    BEGIN
        SET @startDate = DATEADD(MINUTE, DATEDIFF(MINUTE, 0, @EventDate), 0)
        SET @endDate = DATEADD(MINUTE, 1, @startDate)
    END

    if @context = 'second'
    BEGIN
        DECLARE @tempDate DATETIME = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @startDate = DATEADD(SECOND, DATEDIFF(SECOND, @tempDate, @EventDate), @tempDate)
        SET @endDate = DATEADD(SECOND, 1, @startDate)
    END

	DECLARE @voltageEnvelope varchar(max) = (SELECT TOP 1 Value FROM Setting WHERE Name = 'DefaultVoltageEnvelope')

	SELECT 
		Event.LineID AS thelineid, 
		Event.ID AS theeventid, 
		Disturbance.ID as disturbanceid,
		EventType.Name AS disturbancetype,
		Phase.Name AS phase,
        CASE Disturbance.PerUnitMagnitude
            WHEN -1E308 THEN 'NaN'
            ELSE CAST(CONVERT(DECIMAL(4,3), Disturbance.PerUnitMagnitude) AS VARCHAR(8))
        END AS magnitude,
        CASE Disturbance.DurationSeconds
            WHEN -1E308 THEN 'NaN'
            ELSE CAST(CONVERT(DECIMAL(10,3), Disturbance.DurationSeconds) AS VARCHAR(14))
        END AS duration,
		CAST(Disturbance.StartTime AS VARCHAR(26)) AS theinceptiontime,
        dbo.DateDiffTicks('1970-01-01', Disturbance.StartTime) / 10000.0 AS startmillis,
        dbo.DateDiffTicks('1970-01-01', Disturbance.EndTime) / 10000.0 AS endmillis,
		DisturbanceSeverity.SeverityCode,
		MeterLine.LineName + ' ' + [Line].[AssetKey] AS thelinename,
		Line.VoltageKV AS voltage
	FROM
		Event JOIN
		Disturbance ON Disturbance.EventID = Event.ID JOIN
        Disturbance WorstDisturbance ON
            Disturbance.EventID = WorstDisturbance.EventID AND
            Disturbance.PerUnitMagnitude = WorstDisturbance.PerUnitMagnitude AND
            Disturbance.DurationSeconds = WorstDisturbance.DurationSeconds JOIN
		EventType ON Disturbance.EventTypeID = EventType.ID JOIN
		Phase ON Disturbance.PhaseID = Phase.ID JOIN
		DisturbanceSeverity ON Disturbance.ID = DisturbanceSeverity.DisturbanceID JOIN
		Meter ON Meter.ID = @MeterID JOIN
		Line ON Event.LineID = Line.ID JOIN
		MeterLine ON MeterLine.MeterID = @MeterID AND MeterLine.LineID = Line.ID JOIN
		VoltageEnvelope ON VoltageEnvelope.ID = DisturbanceSeverity.VoltageEnvelopeID	
	WHERE
		Event.StartTime >= @startDate AND Event.StartTime < @endDate AND 
		Event.MeterID = @MeterID AND
        WorstDisturbance.PhaseID = @worstPhaseID AND
        Disturbance.PhaseID <> @worstPhaseID AND
		VoltageEnvelope.Name = COALESCE(@voltageEnvelope, 'ITIC')
	ORDER BY
		Event.StartTime ASC

END

GO
/****** Object:  StoredProcedure [dbo].[selectSiteLinesExtensionDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- [selectSiteLinesExtensionDetailsByDate] '01/03/08', '77', 'day'

-- =============================================
CREATE PROCEDURE [dbo].[selectSiteLinesExtensionDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DATETIME
    DECLARE @endDate DATETIME

    IF @context = '180d'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(Day, 180, @startDate)
    END

	IF @context = '90d'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(Day, 90, @startDate)
    END

    IF @context = 'month'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(Day, 30, @startDate)
    END

    IF @context = 'week'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(DAY, 7, @startDate)
    END

    IF @context = 'day'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(DAY, 1, @startDate)
    END

    if @context = 'hour'
    BEGIN
        SET @startDate = DATEADD(HOUR, DATEDIFF(HOUR, 0, @EventDate), 0)
        SET @endDate = DATEADD(HOUR, 1, @startDate)
    END

    if @context = 'minute'
    BEGIN
        SET @startDate = DATEADD(MINUTE, DATEDIFF(MINUTE, 0, @EventDate), 0)
        SET @endDate = DATEADD(MINUTE, 1, @startDate)
    END

    if @context = 'second'
    BEGIN
        DECLARE @tempDate DATETIME = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @startDate = DATEADD(SECOND, DATEDIFF(SECOND, @tempDate, @EventDate), @tempDate)
        SET @endDate = DATEADD(SECOND, 1, @startDate)
    END

    DECLARE @localEventDate DATE = CAST(@EventDate AS DATE)
    DECLARE @localMeterID INT = CAST(@MeterID AS INT)

    DECLARE @MiddleStatment NVARCHAR(MAX) = N''
    DECLARE @SQLStatement NVARCHAR(MAX) = N''

    SELECT @MiddleStatment = @MiddleStatment +  '
                SELECT  Event.ID as EventID,
                        Event.StartTime as StartTime,
                        '''+ t.ServiceName + ''' as ServiceType,
                        MeterLine.LineName + '' '' + [Line].[AssetKey] AS LineName,
                        Line.VoltageKV AS Voltage,
						CAST(dbo.'+ t.HasResultFunction+'(Event.ID) as varchar(max)) as Confidence
                FROM    #temp as Event JOIN
                        Meter ON Meter.ID = Event.MeterID JOIN
                        Line ON Event.LineID = Line.ID JOIN
                        MeterLine ON MeterLine.MeterID = Event.MeterID AND MeterLine.LineID = Line.ID
                WHERE   dbo.' + t.HasResultFunction +'(Event.ID) != '''' UNION'

    FROM (Select * FROM EASExtension) AS t

    SET @MiddleStatment = SUBSTRING(@MiddleStatment,0, LEN(@MiddleStatment) - LEN('UNION'))

    SET @SQLStatement =
        '
        SELECT * INTO #temp
        FROM EVENT
        WHERE   StartTime Between @startDate AND @endDate AND
                MeterID = @localMeterID

        ' + @MiddleStatment + '

         DROP TABLE #temp
 '

    exec sp_executesql @SQLStatement, N'@localMeterID int, @startDate DATETIME, @endDate DATETIME ', @localMeterID = @localMeterID, @startDate = @startDate, @endDate = @endDate

END


GO
/****** Object:  StoredProcedure [dbo].[selectSitesDisturbancesDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesDisturbancesDetailsByDate '10/10/14', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'day'
-- selectSitesDisturbancesDetailsByDate '10/10/14 05:00 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'hour'
-- selectSitesDisturbancesDetailsByDate '10/10/14 05:15 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'minute'
-- selectSitesDisturbancesDetailsByDate '10/10/14 05:15:07 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'second'
-- =============================================
CREATE PROCEDURE [dbo].[selectSitesDisturbancesDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

	DECLARE @startDate DateTime = @EventDate
	DECLARE @endDate DateTime

	if @context = 'day'
		SET @endDate = DATEADD(DAY, 1, @startDate);
	if @context = 'hour'
		SET @endDate = DATEADD(HOUR, 1, @startDate);
	if @context = 'minute'
		SET @endDate = DATEADD(MINUTE, 1, @startDate);
	if @context = 'second'
		SET @endDate = DATEADD(SECOND, 1, @startDate);

	DECLARE @PivotColumns NVARCHAR(MAX) = N''
	DECLARE @ReturnColumns NVARCHAR(MAX) = N''
	DECLARE @SQLStatement NVARCHAR(MAX) = N''

	create table #TEMP (Name varchar(max))
	insert into #TEMP SELECT SeverityCode FROM (Select Distinct SeverityCode FROM DisturbanceSeverity) as t

	SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(Name as varchar(5)), '') + '],' 
	FROM #TEMP ORDER BY Name desc

	SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(Name as varchar(5)), '') + '], 0) AS [' + COALESCE(CAST(Name as varchar(5)), '') + '],' 
	FROM #TEMP ORDER BY Name desc
	DECLARE @voltageEnvelope varchar(max) = (SELECT TOP 1 Value FROM Setting WHERE Name = 'DefaultVoltageEnvelope')

	SET @SQLStatement =
	' SELECT (SELECT TOP 1 ID FROM Event WHERE MeterID = pvt.MeterID AND StartTime >= @startDate AND StartTime < @endDate) 
			 EventID, 
			 MeterID, 
			 Site, 
			 ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
	 FROM ( 
		SELECT 
			Event.MeterID, COUNT(*) AS EventCount, SeverityCode, Meter.Name as Site 
		FROM 
			Disturbance JOIN 
			DisturbanceSeverity ON Disturbance.ID = DisturbanceSeverity.DisturbanceID JOIN
			Event ON Disturbance.EventID = Event.ID JOIN
			EventType ON Event.EventTypeID = EventType.ID JOIN
			Meter ON Event.MeterID = Meter.ID JOIN
			Phase ON Phase.ID = Disturbance.PhaseID JOIN
			VoltageEnvelope ON VoltageEnvelope.ID = DisturbanceSeverity.VoltageEnvelopeID	
		WHERE
			Phase.Name = ''Worst'' AND 
    		MeterID in (select * from authMeters(@username)) AND MeterID IN (SELECT * FROM String_To_Int_Table( @MeterID,  '','')) AND 
			VoltageEnvelope.Name = COALESCE(@voltageEnvelope, ''ITIC'') AND										 
			Event.StartTime >= @startDate AND Event.StartTime < @endDate  
	    GROUP BY Event.MeterID,Meter.Name,SeverityCode
	       ) as ed 
	 PIVOT( 
			SUM(ed.EventCount)
			FOR ed.SeverityCode IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ') 
	 ) as pvt
	 ORDER BY MeterID '

	print @startDate
	print @endDate
	print @sqlstatement
	exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @voltageEnvelope VARCHAR(MAX) ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @voltageEnvelope = @voltageEnvelope
END


GO
/****** Object:  StoredProcedure [dbo].[selectSitesExtensionsDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Billy Ernest>
-- Create date: <Create Date, Mar 06, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesExtensionsDetailsByDate '11/06/2008', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'day'
-- selectSitesExtensionsDetailsByDate '11/06/2008 05:00 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'hour'
-- selectSitesExtensionsDetailsByDate '11/06/2008 05:08 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'minute'
-- selectSitesExtensionsDetailsByDate '11/06/2008 05:08:47 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'second'
-- =============================================

CREATE PROCEDURE [dbo].[selectSitesExtensionsDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DateTime = @EventDate
    DECLARE @endDate DateTime

    if @context = 'day'
        SET @endDate = DATEADD(DAY, 1, @startDate);
    if @context = 'hour'
        SET @endDate = DATEADD(HOUR, 1, @startDate);
    if @context = 'minute'
        SET @endDate = DATEADD(MINUTE, 1, @startDate);
    if @context = 'second'
        SET @endDate = DATEADD(SECOND, 1, @startDate);

    DECLARE @PivotColumns NVARCHAR(MAX) = N''
    DECLARE @ReturnColumns NVARCHAR(MAX) = N''
    DECLARE @SQLStatement NVARCHAR(MAX) = N''
    DECLARE @MiddleStatment NVARCHAR(MAX) = N''

    SELECT @PivotColumns = @PivotColumns + '[' + t.ServiceName + '],'
    FROM (Select ServiceName FROM EASExtension) AS t

    SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + t.ServiceName + '], 0) AS [' + t.ServiceName + '],'
    FROM (Select ServiceName FROM EASExtension) AS t

    SELECT @MiddleStatment = @MiddleStatment +  '
            SELECT MeterID,
                '''+ t.ServiceName + ''' as ServiceName,
                Count(*) as EventCount
            FROM    #temp
            WHERE   dbo.' + t.HasResultFunction + '(ID) != ''''
            GROUP BY MeterID UNION'

    FROM (Select * FROM EASExtension) AS t

    SET @SQLStatement =
    '
    SELECT * INTO #temp
    FROM EVENT
    WHERE   StartTime Between @startDate AND @endDate AND
            MeterID in (select * from authMeters(@username)) AND
            MeterID IN (SELECT * FROM String_To_Int_Table( @MeterID,  '',''))

    SELECT (SELECT TOP 1 ID FROM Event WHERE MeterID = Meter.ID AND StartTime >= @startDate AND StartTime < @endDate) as EventID,
             Meter.ID as MeterID,
             Meter.Name as Site,
             ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
     FROM Meter Join
        (
            ' + SUBSTRING(@MiddleStatment,0, LEN(@MiddleStatment) - LEN('UNION')) + '
         ) as ed
         PIVOT(
                SUM(ed.EventCount)
                FOR ed.ServiceName IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
         ) as pvt ON pvt.MeterID = Meter.ID
     WHERE
        Meter.ID in (select * from authMeters(@username)) AND Meter.ID IN (SELECT * FROM String_To_Int_Table( @MeterID,  '',''))

     ORDER BY MeterID
     DROP Table #temp
     '

    --print @startDate
    --print @endDate
    print @sqlstatement
    exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate

END

GO
/****** Object:  StoredProcedure [dbo].[selectSitesTrendingDataDetailsByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
-- selectSitesTrendingDataDetailsByDate '07/05/2008', 'Voltage RMS','199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external'
-- =============================================
CREATE PROCEDURE [dbo].[selectSitesTrendingDataDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime2,
    @colorScaleName VARCHAR(200),
    @MeterID AS nvarchar(MAX),
    @username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

    DECLARE  @MeterIDs TABLE (ID int);
    DECLARE  @ChannelID AS nvarchar(MAX);
    DECLARE  @Date as DateTime2;
    SET  @Date = CAST(@EventDate AS DATE)

    -- Create MeterIDs Table
    INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
        Meter.ID as meterid,
        Meter.Name as Name,
        Channel.ID as channelid,
        DailyTrendingSummary.Date as date,
        MIN(Minimum/COALESCE(Channel.PerUnitValue,1)) as Minimum,
        MAX(Maximum/COALESCE(Channel.PerUnitValue,1)) as Maximum,
        AVG(Average/COALESCE(Channel.PerUnitValue,1)) as Average,
        MeasurementCharacteristic.Name as characteristic,
        MeasurementType.Name as measurementtype,
        Phase.Name as phasename
    FROM
        DailyTrendingSummary JOIN
        Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
        Meter ON Meter.ID = Channel.MeterID JOIN
        MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
        MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
        Phase ON Channel.PhaseID = Phase.ID
    WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND Channel.ID IN (SELECT ChannelID FROM ContourChannel WHERE ContourColorScaleName = @colorScaleName) AND Date = @Date
    GROUP BY Date, Meter.ID, Meter.Name, MeasurementCharacteristic.Name, MeasurementType.Name, Phase.Name, Channel.ID
    ORDER BY Date
END

GO
/****** Object:  StoredProcedure [dbo].[selectSitesTrendingDataDetailsByDateCurrent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
-- selectSitesTrendingDataDetailsByDateCurrent '07/05/2008', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================
CREATE PROCEDURE [dbo].[selectSitesTrendingDataDetailsByDateCurrent]
    -- Add the parameters for the stored procedure here
	@EventDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @Date as DateTime2;
	SET @Date = @EventDate;

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID as meterid,
		Meter.Name as Name,
		Channel.ID as channelid,
		DailyTrendingSummary.Date as date,
		MIN(Minimum) as Minimum,
		MAX(Maximum) as Maximum,
		AVG(Average) as Average, 
		MeasurementCharacteristic.Name as characteristic,
		MeasurementType.Name as measurementtype,
		Phase.Name as phasename
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID JOIN 
		MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
		MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
		Phase ON Channel.PhaseID = Phase.ID
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND MeasurementType.Name = 'Current' AND Date = @Date
		GROUP BY Date, Meter.ID, Meter.Name, MeasurementCharacteristic.Name, MeasurementType.Name, Phase.Name, Channel.ID
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectSitesTrendingDataDetailsByDatePower]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
-- selectSitesTrendingDataDetailsByDatePower '07/05/2008', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================
CREATE PROCEDURE [dbo].[selectSitesTrendingDataDetailsByDatePower]
    -- Add the parameters for the stored procedure here
	@EventDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @Date as DateTime2;
	SET @Date = @EventDate;

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID as meterid,
		Meter.Name as Name,
		Channel.ID as channelid,
		DailyTrendingSummary.Date as date,
		MIN(Minimum) as Minimum,
		MAX(Maximum) as Maximum,
		AVG(Average) as Average, 
		MeasurementCharacteristic.Name as characteristic,
		MeasurementType.Name as measurementtype,
		Phase.Name as phasename
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID JOIN 
		MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
		MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
		Phase ON Channel.PhaseID = Phase.ID
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND MeasurementType.Name = 'Power' AND Date = @Date
		GROUP BY Date, Meter.ID, Meter.Name, MeasurementCharacteristic.Name, MeasurementType.Name, Phase.Name, Channel.ID
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectSitesTrendingDataDetailsByDateVoltage]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, 8/4/2016>
-- Description: <Description, Selects Trending Data for a set of sites by Date>
-- selectSitesTrendingDataDetailsByDateVoltage '07/05/2008', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================
CREATE PROCEDURE [dbo].[selectSitesTrendingDataDetailsByDateVoltage]
    -- Add the parameters for the stored procedure here
	@EventDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @Date as DateTime2;
	SET @Date = @EventDate;

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID as meterid,
		Meter.Name as Name,
		Channel.ID as channelid,
		DailyTrendingSummary.Date as date,
		MIN(Minimum/COALESCE(Channel.PerUnitValue,1)) as Minimum,
		MAX(Maximum/COALESCE(Channel.PerUnitValue,1)) as Maximum,
		AVG(Average/COALESCE(Channel.PerUnitValue,1)) as Average, 
		MeasurementCharacteristic.Name as characteristic,
		MeasurementType.Name as measurementtype,
		Phase.Name as phasename
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID JOIN 
		MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
		MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
		Phase ON Channel.PhaseID = Phase.ID
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND MeasurementType.Name = 'Voltage' AND Date = @Date
		GROUP BY Date, Meter.ID, Meter.Name, MeasurementCharacteristic.Name, MeasurementType.Name, Phase.Name, Channel.ID
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataByChannelByDate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataByChannelByDate] '07/05/2008', '08/04/2008', 'Voltage RMS','199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external'
-- =============================================
CREATE PROCEDURE [dbo].[selectTrendingDataByChannelByDate]
    @StartDate DateTime2,
    @EndDate DateTime2,
    @colorScale AS varchar(200),
    @MeterID AS nvarchar(MAX),
    @username AS nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE  @MeterIDs TABLE (ID int);
    DECLARE  @ChannelID AS nvarchar(MAX);
    DECLARE  @BeginDate DateTime2;
    DECLARE  @StopDate DateTime2;

    SET @BeginDate = @StartDate;
    SET @StopDate = @EndDate;

    -- Create MeterIDs Table
    INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
        Date,
        MIN(Minimum/COALESCE(Channel.PerUnitValue, 1)) as Minimum,
        MAX(Maximum/COALESCE(Channel.PerUnitValue,1)) as Maximum,
        AVG(Average/COALESCE(Channel.PerUnitValue,1)) as Average
    FROM
        DailyTrendingSummary JOIN
        Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
        Meter ON Meter.ID = Channel.MeterID
    WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND Channel.ID IN (SELECT ChannelID FROM ContourChannel WHERE ContourChannel.ContourColorScaleName = @colorScale) AND Date >= @BeginDate AND Date <= @StopDate
    GROUP BY Date
    ORDER BY Date
END

GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataByChannelByDateCurrent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataByChannelByDateCurrent] '07/05/2008', '08/04/2010', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataByChannelByDateCurrent]
    @StartDate DateTime2,
	@EndDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Date,
		MIN(Minimum) as Minimum,
		MAX(Maximum) as Maximum,
		AVG(Average) as Average
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND Channel.MeasurementTypeID = 2 AND Date >= @StartDate AND Date <= @EndDate
		GROUP BY Date
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataByChannelByDatePower]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataByChannelByDatePower] '07/05/2008', '08/04/2016', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataByChannelByDatePower]
    @StartDate DateTime2,
	@EndDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Date,
		MIN(Minimum) as Minimum,
		MAX(Maximum) as Maximum,
		AVG(Average) as Average
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID

		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND Channel.MeasurementTypeID = 3 AND Date >= @StartDate AND Date <= @EndDate
		GROUP BY Date
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataByChannelByDateVoltage]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataByChannelByDateVoltage] '07/05/2008', '08/04/2008', 'Voltage RMS','199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataByChannelByDateVoltage]
    @StartDate DateTime2,
	@EndDate DateTime2,
	@colorScale AS varchar(200),
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @BeginDate DateTime2;
	DECLARE  @StopDate DateTime2;

	SET @BeginDate = @StartDate;
	SET @StopDate = @EndDate;

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Date,
		MIN(Minimum/Channel.PerUnitValue) as Minimum,
		MAX(Maximum/Channel.PerUnitValue) as Maximum,
		AVG(Average/Channel.PerUnitValue) as Average
    FROM
        DailyTrendingSummary JOIN 
		Channel ON DailyTrendingSummary.ChannelID = Channel.ID JOIN
		Meter ON Meter.ID = Channel.MeterID 
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs) AND Channel.ID IN (SELECT ChannelID FROM ContourChannel WHERE ContourChannel.ContourColorScaleName = @colorScale) AND Date >= @BeginDate AND Date <= @StopDate
		GROUP BY Date
		ORDER BY Date    
END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataByChannelIDDate2]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day>
-- selectTrendingDataByChannelIDDate2 '9/15/2015', 988
-- =============================================
CREATE PROCEDURE [dbo].[selectTrendingDataByChannelIDDate2]
    @EventDate DateTime2,
    @ChannelID int
AS
BEGIN
    SET NOCOUNT ON;

    -- Trending Data
    WITH TrendingDataPoint AS
    (
        SELECT
            ChannelID,
            SeriesType,
            Time,
            Value
        FROM
            GetTrendingData(@EventDate, DATEADD(NANOSECOND, -100, DATEADD(DAY, 1, @EventDate)), @ChannelID, default) AS TrendingData JOIN
            (
                SELECT 0 AS ID, 'Minimum' AS SeriesType UNION
                SELECT 1 AS ID, 'Maximum' AS SeriesType UNION
                SELECT 2 AS ID, 'Average' AS SeriesType
            ) AS Series ON TrendingData.SeriesID = Series.ID
    ),
    TrendingData AS
    (
        SELECT
            ChannelID,
            Time,
            Maximum,
            Minimum,
            Average
        FROM TrendingDataPoint
        PIVOT
        (
            SUM(Value)
            FOR SeriesType IN (Maximum, Minimum, Average)
        ) AS TrendingData
    )
    SELECT
        TrendingData.Time AS thedate,
        TrendingData.Minimum AS theminimum,
        TrendingData.Maximum AS themaximum,
        TrendingData.Average AS theaverage
    FROM
        TrendingData
    WHERE
        TrendingData.ChannelID = @ChannelID
    ORDER BY TrendingData.Time

    -- Alarm Data
    DECLARE @alarmHigh FLOAT
    DECLARE @alarmLow FLOAT

    SELECT
        @EventDate AS thedatefrom,
        DATEADD(DAY, 1, @EventDate) AS thedateto,
        CASE
            WHEN AlarmRangeLimit.PerUnit <> 0 AND Channel.PerUnitValue IS NOT NULL THEN AlarmRangeLimit.High * PerUnitValue
            ELSE AlarmRangeLimit.High
        END AS alarmlimithigh,
        CASE
            WHEN AlarmRangeLimit.PerUnit <> 0 AND Channel.PerUnitValue IS NOT NULL THEN AlarmRangeLimit.Low * PerUnitValue
            ELSE AlarmRangeLimit.Low
        END AS alarmlimitlow
    FROM
        AlarmRangeLimit JOIN
        Channel ON AlarmRangeLimit.ChannelID = Channel.ID
    WHERE
        AlarmRangeLimit.AlarmTypeID = (SELECT ID FROM AlarmType WHERE Name = 'Alarm') AND
        AlarmRangeLimit.ChannelID = @ChannelID

    -- Off-normal data
    DECLARE @dayOfWeek INT = DATEPART(DW, @EventDate) - 1
    DECLARE @hourOfWeek INT = @dayOfWeek * 24

    ; WITH HourlyIndex AS
    (
        SELECT @hourOfWeek AS HourOfWeek
        UNION ALL
        SELECT HourOfWeek + 1
        FROM HourlyIndex
        WHERE (HourOfWeek + 1) < @hourOfWeek + 24
    )
    SELECT
        DATEADD(HOUR, HourlyIndex.HourOfWeek - @hourOfWeek, @EventDate) AS thedatefrom,
        DATEADD(HOUR, HourlyIndex.HourOfWeek - @hourOfWeek + 1, @EventDate) AS thedateto,
        HourOfWeekLimit.High AS offlimithigh,
        HourOfWeekLimit.Low AS offlimitlow
    FROM
        HourlyIndex LEFT OUTER JOIN
        HourOfWeekLimit ON HourOfWeekLimit.HourOfWeek = HourlyIndex.HourOfWeek
    WHERE
        HourOfWeekLimit.ChannelID IS NULL OR
        HourOfWeekLimit.ChannelID = @ChannelID
END

GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataForMeterIDsByDateCurrent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataForMeterIDsByDateCurrent] '07/05/2008', '08/04/2010', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataForMeterIDsByDateCurrent]
    @StartDate DateTime2,
	@EndDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID,
		Meter.Name,
		Data.Minimum,
		Data.Maximum,
		Data.Average
    FROM
		Meter LEFT JOIN
		( SELECT Channel.MeterID as MID,
			     MIN(Minimum) as Minimum,
				 MAX(Maximum) as Maximum,
				 AVG(Average) as Average

		  FROM Channel JOIN 
			   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID
		  WHERE Channel.MeasurementTypeID = 2 AND Date >= @StartDate AND Date <= @EndDate
		  GROUP BY Channel.MeterID

		) as Data ON Data.MID = Meter.ID 
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs)

END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataForMeterIDsByDatePower]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataForMeterIDsByDatePower] '07/05/2008', '08/04/2010', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 

-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataForMeterIDsByDatePower]
    @StartDate DateTime2,
	@EndDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID,
		Meter.Name,
		Data.Minimum,
		Data.Maximum,
		Data.Average
    FROM
		Meter LEFT JOIN
		( SELECT Channel.MeterID as MID,
			     MIN(Minimum) as Minimum,
				 MAX(Maximum) as Maximum,
				 AVG(Average) as Average

		  FROM Channel JOIN 
			   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID
		  WHERE Channel.MeasurementTypeID = 3 AND Date >= @StartDate AND Date <= @EndDate
		  GROUP BY Channel.MeterID

		) as Data ON Data.MID = Meter.ID 
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs)

END


GO
/****** Object:  StoredProcedure [dbo].[selectTrendingDataForMeterIDsByDateVoltage]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, William Ernest>
-- Create date: <Create Date, Aug 4, 2016>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day for purpose of creating smart alarms in openXDA/Historian>
-- [dbo].[selectTrendingDataForMeterIDsByDateVoltage] '07/05/2008', '08/04/2008', '199,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,200,201,1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125', 'external' 
-- [dbo].[selectTrendingDataForMeterIDsByDateVoltage] '07/05/2010', '08/04/2010', '199,126,127,128,129,130,131,132,133,134,135', 'external' 
-- =============================================

CREATE PROCEDURE [dbo].[selectTrendingDataForMeterIDsByDateVoltage]
    @StartDate DateTime2,
	@EndDate DateTime2,
    @MeterID AS nvarchar(MAX),
	@username AS nvarchar(4000)

AS
BEGIN
    SET NOCOUNT ON;

	DECLARE  @MeterIDs TABLE (ID int);
	DECLARE  @ChannelID AS nvarchar(MAX);
	DECLARE  @BeginDate DateTime2;
	DECLARE  @StopDate DateTime2;

	SET @BeginDate = @StartDate;
	SET @StopDate = @EndDate;

	-- Create MeterIDs Table
	INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

    -- Trending Data
    SELECT
		Meter.ID,
		Meter.Name,
		Data.Minimum,
		Data.Maximum,
		Data.Average
    FROM
		Meter LEFT JOIN
		( SELECT Channel.MeterID as MID,
			     MIN(Minimum) as Minimum,
				 MAX(Maximum) as Maximum,
				 AVG(Average) as Average

		  FROM Channel JOIN 
			   DailyTrendingSummary ON  DailyTrendingSummary.ChannelID = Channel.ID
		  WHERE Channel.MeasurementTypeID = 1 AND Date >= @BeginDate AND Date <= @StopDate
		  GROUP BY Channel.MeterID

		) as Data ON Data.MID = Meter.ID 
		WHERE Meter.ID IN (SELECT * FROM @MeterIDs)
END


GO
/****** Object:  StoredProcedure [dbo].[UniversalCascadeDelete]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE PROCEDURE [dbo].[UniversalCascadeDelete]
	 
	@tableName VARCHAR(200),
	@baseCriteria NVARCHAR(1000)
AS
BEGIN
	 
	 
	SET NOCOUNT ON;
	DECLARE @deleteSQL NVARCHAR(900)

	CREATE TABLE #DeleteCascade
	(
		DeleteSQL NVARCHAR(900)
	)

	INSERT INTO #DeleteCascade
	EXEC usp_delete_cascade @tableName, @baseCriteria

	DECLARE DeleteCursor CURSOR FOR
	SELECT *
	FROM #DeleteCascade

	OPEN DeleteCursor

	FETCH NEXT FROM DeleteCursor
	INTO @deleteSQL

	WHILE @@FETCH_STATUS = 0
	BEGIN
		EXEC sp_executesql @deleteSQL

		FETCH NEXT FROM DeleteCursor
		INTO @deleteSQL
	END

	CLOSE DeleteCursor
	DEALLOCATE DeleteCursor

	DROP TABLE #DeleteCascade
END

GO
/****** Object:  UserDefinedFunction [dbo].[ComputeHash]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE FUNCTION [dbo].[ComputeHash]
(
    @eventID INT,
    @templateID INT
)
RETURNS BIGINT
BEGIN
    DECLARE @md5Hash BINARY(16)

    SELECT @md5Hash = master.sys.fn_repl_hash_binary(CONVERT(VARBINARY(MAX), EventDetail))
    FROM EventDetail
    WHERE EventID = @eventID

    SELECT @md5Hash = master.sys.fn_repl_hash_binary(@md5Hash + CONVERT(VARBINARY(MAX), Template))
    FROM XSLTemplate
    WHERE ID = @templateID

    RETURN CONVERT(BIGINT, SUBSTRING(@md5Hash, 0, 8)) ^ CONVERT(BIGINT, SUBSTRING(@md5Hash, 8, 8))
END

GO
/****** Object:  UserDefinedFunction [dbo].[ComputeValueOnCurve]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author:		<Author, Billy Ernest & Stephen Wills> 
-- Create date: <Create Date, 9/23/2016>
-- Description:	<Description, Takes a curve ID and a duration and returns a value along a benchmark curve>
-- SELECT dbo.ComputeValueOnCurve(2, 0.0002)
-- =============================================
CREATE FUNCTION [dbo].[ComputeValueOnCurve] 
(
	-- Add the parameters for the function here
	@curveID int,
	@duration float
)
RETURNS float
AS
BEGIN
	-- Declare the return variable here
	DECLARE curveCursor CURSOR FOR 
		SELECT PerUnitMagnitude, DurationSeconds 
		FROM VoltageCurvePoint 
		WHERE VoltageCurvePoint.VoltageCurveID = @curveID 
		ORDER BY LoadOrder

	OPEN curveCursor

	DECLARE @m1 float
	DECLARE @d1 float
	DECLARE @m2 float
	DECLARE @d2 float

	FETCH NEXT FROM curveCursor INTO @m1, @d1		
	FETCH NEXT FROM curveCursor INTO @m2, @d2

	IF @duration < @d1 BEGIN
						CLOSE curveCursor
						DEALLOCATE curveCursor
						RETURN 1E+308 
					   END
		
	WHILE @@FETCH_STATUS = 0 AND @duration > @d2
		BEGIN 
		SET @m1 = @m2
		SET @d1 = @d2
		FETCH NEXT FROM curveCursor INTO @m2, @d2
		END
	CLOSE curveCursor
	DEALLOCATE curveCursor

	IF @@FETCH_STATUS <> 0 RETURN @m1
	IF @d1 = @d2 RETURN @m2

	DECLARE @slope float = (@m1 - @m2)/(@d1 - @d2)
	DECLARE @voltResult float = @slope * (@duration - @d1) + @m1
	-- Return the result of the function
	RETURN @voltResult

END



GO
/****** Object:  UserDefinedFunction [dbo].[DateDiffTicks]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[DateDiffTicks]
(
    @startDate DATETIME2,
    @endDate DATETIME2
)
RETURNS BIGINT
AS
BEGIN
    DECLARE @startDay DATETIME2 = DATEADD(DAY, DATEDIFF(DAY, 0, @startDate), 0)
    DECLARE @endDay DATETIME2 = DATEADD(DAY, DATEDIFF(DAY, 0, @endDate), 0)

    DECLARE @startSeconds DATETIME2 = DATEADD(SECOND, DATEDIFF(SECOND, @startDay, @startDate), @startDay)
    DECLARE @endSeconds DATETIME2 = DATEADD(SECOND, DATEDIFF(SECOND, @endDay, @endDate), @endDay)

    RETURN
        (CONVERT(BIGINT, DATEDIFF(DAY, @startDate, @endDate)) * 24 * 60 * 60 * 10000000) -
        (CONVERT(BIGINT, DATEDIFF(SECOND, @startDay, @startDate)) * 10000000) +
        (CONVERT(BIGINT, DATEDIFF(SECOND, @endDay, @endDate)) * 10000000) -
        (DATEDIFF(NANOSECOND, @startSeconds, @startDate) / 100) +
        (DATEDIFF(NANOSECOND, @endSeconds, @endDate) / 100)
END

GO
/****** Object:  UserDefinedFunction [dbo].[GetDisturbanceForEvent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[GetDisturbanceForEvent]
(
    @eventID INT,
    @eventTypeID INT
)
RETURNS @Sequence TABLE
(
    ID INT PRIMARY KEY,
    SequenceNumber INT
)
AS BEGIN
    DECLARE @seq INT
    DECLARE @seqStartTime DATETIME2
    DECLARE @seqEndTime DATETIME2

    DECLARE @disturbanceID INT
    DECLARE @disturbanceStartTime DATETIME2
    DECLARE @disturbanceEndTime DATETIME2

    DECLARE DisturbanceCursor CURSOR FOR
    SELECT ID, StartTime, EndTime
    FROM Disturbance
    WHERE
        EventID = @eventID AND
        EventTypeID = @eventTypeID AND
        PhaseID IN (SELECT ID FROM Phase WHERE Name <> 'Worst')
    ORDER BY StartTime

    OPEN DisturbanceCursor

    FETCH NEXT FROM DisturbanceCursor
    INTO @disturbanceID, @disturbanceStartTime, @disturbanceEndTime

    WHILE @@FETCH_STATUS = 0
    BEGIN
        SELECT
            @seq =
                CASE
                    WHEN @seq IS NULL THEN 1
                    WHEN @disturbanceStartTime <= @seqEndTime THEN @seq
                    ELSE @seq + 1
                END,
            @seqStartTime =
                CASE
                    WHEN @seqStartTime IS NULL THEN @disturbanceStartTime
                    WHEN @disturbanceStartTime <= @seqEndTime THEN @seqStartTime
                    ELSE @disturbanceStartTime
                END,
            @seqEndTime =
                CASE
                    WHEN @seqEndTime IS NULL THEN @disturbanceEndTime
                    WHEN @disturbanceEndTime < @seqEndTime THEN @seqEndTime
                    ELSE @disturbanceEndTime
                END

        INSERT INTO @Sequence
        VALUES(@disturbanceID, @seq)

        FETCH NEXT FROM DisturbanceCursor
        INTO @disturbanceID, @disturbanceStartTime, @disturbanceEndTime
    END

    CLOSE DisturbanceCursor
    DEALLOCATE DisturbanceCursor

    RETURN
END



GO
/****** Object:  UserDefinedFunction [dbo].[GetDisturbancesInSystemEvent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE FUNCTION [dbo].[GetDisturbancesInSystemEvent]
(
    @startTime DATETIME2,
    @endTime DATETIME2,
    @timeTolerance FLOAT
)
RETURNS @Sequence TABLE
(
    ID INT PRIMARY KEY,
    SequenceNumber INT
)
AS BEGIN
    DECLARE @seq INT
    DECLARE @seqStartTime DATETIME2
    DECLARE @seqEndTime DATETIME2

    DECLARE @disturbanceID INT
    DECLARE @disturbanceStartTime DATETIME2
    DECLARE @disturbanceEndTime DATETIME2

    DECLARE DisturbanceCursor CURSOR FOR
    SELECT ID, StartTime, EndTime
    FROM Disturbance
    WHERE
        EventID IN (SELECT * FROM dbo.GetSystemEventIDs(@startTime, @endTime, @timeTolerance)) AND
        PhaseID = (SELECT ID FROM Phase WHERE Name = 'Worst')
    ORDER BY StartTime

    OPEN DisturbanceCursor

    FETCH NEXT FROM DisturbanceCursor
    INTO @disturbanceID, @disturbanceStartTime, @disturbanceEndTime

    WHILE @@FETCH_STATUS = 0
    BEGIN
        SELECT
            @seq =
                CASE
                    WHEN @seq IS NULL THEN 1
                    WHEN @disturbanceStartTime <= @seqEndTime THEN @seq
                    ELSE @seq + 1
                END,
            @seqStartTime =
                CASE
                    WHEN @seqStartTime IS NULL THEN @disturbanceStartTime
                    WHEN @disturbanceStartTime <= @seqEndTime THEN @seqStartTime
                    ELSE @disturbanceStartTime
                END,
            @seqEndTime =
                CASE
                    WHEN @seqEndTime IS NULL THEN @disturbanceEndTime
                    WHEN @disturbanceEndTime < @seqEndTime THEN @seqEndTime
                    ELSE @disturbanceEndTime
                END

        INSERT INTO @Sequence
        VALUES(@disturbanceID, @seq)

        FETCH NEXT FROM DisturbanceCursor
        INTO @disturbanceID, @disturbanceStartTime, @disturbanceEndTime
    END

    CLOSE DisturbanceCursor
    DEALLOCATE DisturbanceCursor

    RETURN
END

GO
/****** Object:  UserDefinedFunction [dbo].[GetTypedTrendingData]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE FUNCTION [dbo].[GetTypedTrendingData](@startTime datetime2, @stopTime datetime2, @channelIDs nvarchar(MAX) = null, @seriesCount int = 3)
RETURNS @trendingData TABLE
(
   [ChannelID] int,
   [SeriesType] varchar(50),
   [Time] datetime2,
   [Value] real
)
AS
BEGIN
	DECLARE @server VARCHAR(MAX)
	DECLARE @instanceName VARCHAR(MAX)

	SELECT
		@server = COALESCE(Server.Value, '127.0.0.1'),
		@instanceName = COALESCE(InstanceName.Value, 'XDA')
	FROM
		(SELECT NULL) AS Dummy(dummy) LEFT OUTER JOIN
		Setting Server ON Server.Name = 'Historian.Server' LEFT OUTER JOIN
		Setting InstanceName ON InstanceName.Name = 'Historian.InstanceName'

	INSERT INTO @trendingData
	SELECT
		ChannelID,
		CASE SeriesID
			WHEN 0 THEN 'Minimum'
			WHEN 1 THEN 'Maximum'
			WHEN 2 THEN 'Average'
			ELSE 'Unknown'
		END AS SeriesType,
		Time,
		Value
	FROM ExternalGetTrendingData(@server, @instanceName, @startTime, @stopTime, @channelIDs, @seriesCount)

	RETURN
END



GO
/****** Object:  Table [dbo].[AlarmEmailCriterion]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[AlarmEmailCriterion](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[MeasurementTypeID] [int] NOT NULL,
	[MeasurementCharacteristicID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[ApplicationRole]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[ApplicationRole](
	[ID] [uniqueidentifier] NOT NULL DEFAULT (newid()),
	[Name] [varchar](200) NOT NULL,
	[Description] [varchar](max) NULL,
	[NodeID] [uniqueidentifier] NOT NULL DEFAULT ('00000000-0000-0000-0000-000000000000'),
	[CreatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[CreatedBy] [varchar](200) NOT NULL DEFAULT (suser_name()),
	[UpdatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[UpdatedBy] [varchar](200) NOT NULL DEFAULT (suser_name()),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[ApplicationRoleSecurityGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ApplicationRoleSecurityGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ApplicationRoleID] [uniqueidentifier] NOT NULL,
	[SecurityGroupID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[ApplicationRoleUserAccount]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ApplicationRoleUserAccount](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ApplicationRoleID] [uniqueidentifier] NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[AuditLog]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[AuditLog](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[TableName] [varchar](200) NOT NULL,
	[PrimaryKeyColumn] [varchar](200) NOT NULL,
	[PrimaryKeyValue] [varchar](max) NOT NULL,
	[ColumnName] [varchar](200) NOT NULL,
	[OriginalValue] [varchar](max) NULL,
	[NewValue] [varchar](max) NULL,
	[Deleted] [bit] NOT NULL CONSTRAINT [DF_AuditLog_Deleted]  DEFAULT ((0)),
	[UpdatedBy] [varchar](200) NULL CONSTRAINT [DF_AuditLog_UpdatedBy]  DEFAULT (suser_name()),
	[UpdatedOn] [datetime] NULL CONSTRAINT [DF_AuditLog_UpdatedOn]  DEFAULT (getutcdate()),
 CONSTRAINT [PK_AuditLog] PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[BreakerEmailCriterion]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[BreakerEmailCriterion](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[BreakerOperationTest]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[BreakerOperationTest](
	[BreakerOperationID] [int] NULL,
	[APhaseCleared] [datetime2](7) NULL,
	[BPhaseCleared] [datetime2](7) NULL,
	[CPhaseCleared] [datetime2](7) NULL
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[ChannelAlarmSummary]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ChannelAlarmSummary](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ChannelID] [int] NOT NULL,
	[AlarmTypeID] [int] NOT NULL,
	[Date] [date] NOT NULL,
	[AlarmPoints] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[ContourAnimation]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[ContourAnimation](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ColorScaleName] [varchar](200) NOT NULL,
	[StartTime] [datetime] NOT NULL,
	[EndTime] [datetime] NOT NULL,
	[StepSize] [int] NOT NULL,
	[AccessedOn] [datetime] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[ContourAnimationFrame]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[ContourAnimationFrame](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ContourAnimationID] [int] NOT NULL,
	[FrameIndex] [int] NOT NULL,
	[FrameImage] [varbinary](max) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[ContourChannelType]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ContourChannelType](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ContourColorScaleID] [int] NOT NULL,
	[MeasurementTypeID] [int] NOT NULL,
	[MeasurementCharacteristicID] [int] NOT NULL,
	[PhaseID] [int] NOT NULL,
	[HarmonicGroup] [int] NOT NULL DEFAULT ((0)),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[ContourColorScale]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[ContourColorScale](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
	[NominalValue] [float] NOT NULL DEFAULT ((0.0)),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[ContourColorScalePoint]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ContourColorScalePoint](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ContourColorScaleID] [int] NOT NULL,
	[Value] [float] NOT NULL,
	[Color] [int] NOT NULL,
	[OrderID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[DeviceFilter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[DeviceFilter](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[UserAccount] [varchar](500) NOT NULL,
	[Name] [nvarchar](500) NOT NULL,
	[FilterExpression] [nvarchar](max) NOT NULL,
	[MeterGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[DisturbanceEmailCriterion]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[DisturbanceEmailCriterion](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[SeverityCode] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[DisturbanceSeverity]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[DisturbanceSeverity](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[VoltageEnvelopeID] [int] NOT NULL,
	[DisturbanceID] [int] NOT NULL,
	[SeverityCode] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EASExtension]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[EASExtension](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[ServiceName] [varchar](50) NOT NULL,
	[HasResultFunction] [varchar](50) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[EmailCategory]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[EmailCategory](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](50) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[EmailGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[EmailGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[EmailGroupLineGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailGroupLineGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[LineGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY],
UNIQUE NONCLUSTERED 
(
	[EmailGroupID] ASC,
	[LineGroupID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EmailGroupMeterGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailGroupMeterGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[MeterGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY],
UNIQUE NONCLUSTERED 
(
	[EmailGroupID] ASC,
	[MeterGroupID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EmailGroupSecurityGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailGroupSecurityGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[SecurityGroupID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY],
UNIQUE NONCLUSTERED 
(
	[EmailGroupID] ASC,
	[SecurityGroupID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EmailGroupType]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailGroupType](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[EmailTypeID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY],
UNIQUE NONCLUSTERED 
(
	[EmailGroupID] ASC,
	[EmailTypeID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EmailGroupUserAccount]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailGroupUserAccount](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY],
UNIQUE NONCLUSTERED 
(
	[EmailGroupID] ASC,
	[UserAccountID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EmailType]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EmailType](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailCategoryID] [int] NOT NULL,
	[XSLTemplateID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EventNote]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[EventNote](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EventID] [int] NOT NULL,
	[Note] [varchar](max) NOT NULL,
	[UserAccount] [varchar](max) NOT NULL,
	[Timestamp] [datetime] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[EventOveride]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EventOveride](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EventID] [int] NOT NULL,
	[EventTypeID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[EventSentEmail]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[EventSentEmail](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EventID] [int] NOT NULL,
	[SentEmailID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[FaultCurveStatistic]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[FaultCurveStatistic](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[FaultCurveID] [int] NOT NULL,
	[FaultNumber] [int] NOT NULL,
	[Maximum] [float] NOT NULL,
	[Minimum] [float] NOT NULL,
	[Average] [float] NOT NULL,
	[StandardDeviation] [float] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[FaultEmailCriterion]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[FaultEmailCriterion](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[EmailGroupID] [int] NOT NULL,
	[EmailOnReclose] [int] NOT NULL DEFAULT ((0)),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[FaultNote]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[FaultNote](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[FaultSummaryID] [int] NOT NULL,
	[Note] [varchar](max) NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
	[Timestamp] [datetime] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[FileBlob]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[FileBlob](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Blob] [varbinary](max) NOT NULL,
	[DataFileID] [int] NOT NULL,
PRIMARY KEY NONCLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[FileGroupLocalToRemote]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[FileGroupLocalToRemote](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[LocalFileGroupID] [int] NOT NULL,
	[RemoteFileGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[LineGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[LineGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[LineLineGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[LineLineGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[LineID] [int] NOT NULL,
	[LineGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[LinesToDataPush]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[LinesToDataPush](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[LocalXDALineID] [int] NOT NULL,
	[RemoteXDALineID] [int] NULL,
	[LocalXDAAssetKey] [varchar](200) NOT NULL,
	[RemoteXDAAssetKey] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[MeterAlarmSummary]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[MeterAlarmSummary](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[MeterID] [int] NOT NULL,
	[AlarmTypeID] [int] NOT NULL,
	[Date] [date] NOT NULL,
	[AlarmPoints] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[MeterGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[MeterGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[MeterMeterGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[MeterMeterGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[MeterID] [int] NOT NULL,
	[MeterGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[MeterSignal]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[MeterSignal](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[MeterID] [int] NOT NULL,
	[Category] [varchar](50) NOT NULL,
	[SignalID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[MetersToDataPush]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[MetersToDataPush](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[LocalXDAMeterID] [int] NOT NULL,
	[RemoteXDAMeterID] [int] NULL,
	[LocalXDAAssetKey] [varchar](200) NOT NULL,
	[RemoteXDAAssetKey] [varchar](200) NOT NULL,
	[RemoteXDAName] [varchar](20) NOT NULL,
	[Obsfucate] [bit] NOT NULL,
	[Synced] [bit] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[MeterType]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[MeterType](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](25) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[PQIResult]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[PQIResult](
	[ID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[PQMarkAggregate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[PQMarkAggregate](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[MeterID] [int] NOT NULL,
	[Year] [int] NOT NULL,
	[Month] [int] NOT NULL,
	[ITIC] [int] NOT NULL,
	[SEMI] [int] NOT NULL,
	[SARFI90] [int] NOT NULL,
	[SARFI70] [int] NOT NULL,
	[SARFI50] [int] NOT NULL,
	[SARFI10] [int] NOT NULL,
	[THDJson] [varchar](max) NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[PQMarkCompany]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[PQMarkCompany](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[PQMarkCompanyMeter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[PQMarkCompanyMeter](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[PQMarkCompanyID] [int] NOT NULL,
	[MeterID] [int] NOT NULL,
	[DisplayName] [varchar](200) NOT NULL,
	[Enabled] [bit] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[PQMarkDuration]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[PQMarkDuration](
	[ID] [int] NOT NULL,
	[Label] [nvarchar](50) NOT NULL,
	[Min] [float] NOT NULL,
	[Max] [float] NOT NULL,
	[LoadOrder] [int] NOT NULL
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[PQMarkRestrictedTableUserAccount]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[PQMarkRestrictedTableUserAccount](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[PrimaryID] [int] NOT NULL,
	[TableName] [varchar](max) NOT NULL,
	[UserAccount] [varchar](max) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[PQMarkVoltageBin]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[PQMarkVoltageBin](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Label] [nvarchar](50) NOT NULL,
	[Min] [float] NOT NULL,
	[Max] [float] NOT NULL,
	[LoadOrder] [int] NOT NULL
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[RemoteXDAInstance]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[RemoteXDAInstance](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
	[Address] [varchar](200) NULL,
	[Frequency] [varchar](20) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[RemoteXDAInstanceMeter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[RemoteXDAInstanceMeter](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[RemoteXDAInstanceID] [int] NOT NULL,
	[MetersToDataPushID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[SavedViews]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO
CREATE TABLE [dbo].[SavedViews](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[UserAccount] [varchar](500) NOT NULL,
	[Name] [nvarchar](500) NOT NULL,
	[DateRange] [int] NOT NULL,
	[FromDate] [datetime] NOT NULL,
	[ToDate] [datetime] NOT NULL,
	[Tab] [nvarchar](20) NOT NULL,
	[DeviceFilterID] [int] NOT NULL,
	[MapGrid] [nvarchar](5) NOT NULL,
	[IsDefault] [bit] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[SecurityGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[SecurityGroup](
	[ID] [uniqueidentifier] NOT NULL DEFAULT (newid()),
	[Name] [varchar](200) NOT NULL,
	[Description] [varchar](max) NULL,
	[CreatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[CreatedBy] [varchar](200) NOT NULL DEFAULT (suser_name()),
	[UpdatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[UpdatedBy] [varchar](200) NOT NULL DEFAULT (suser_name()),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[SecurityGroupUserAccount]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[SecurityGroupUserAccount](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[SecurityGroupID] [uniqueidentifier] NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[SentEmail]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[SentEmail](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[TimeSent] [datetime] NOT NULL,
	[ToLine] [varchar](max) NOT NULL,
	[Subject] [varchar](500) NOT NULL,
	[Message] [varchar](max) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[StatusChatter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[StatusChatter](
	[EventID] [int] NULL,
	[Count] [int] NULL
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[UserAccount]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[UserAccount](
	[ID] [uniqueidentifier] NOT NULL DEFAULT (newid()),
	[Name] [varchar](200) NOT NULL,
	[Password] [varchar](200) NULL,
	[FirstName] [varchar](200) NULL,
	[LastName] [varchar](200) NULL,
	[DefaultNodeID] [uniqueidentifier] NOT NULL DEFAULT ('00000000-0000-0000-0000-000000000000'),
	[Phone] [varchar](200) NULL,
	[Email] [varchar](200) NULL,
	[LockedOut] [bit] NOT NULL DEFAULT ((0)),
	[UseADAuthentication] [bit] NOT NULL DEFAULT ((1)),
	[ChangePasswordOn] [datetime] NULL DEFAULT (dateadd(day,(90),getutcdate())),
	[CreatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[CreatedBy] [varchar](50) NOT NULL DEFAULT (suser_name()),
	[UpdatedOn] [datetime] NOT NULL DEFAULT (getutcdate()),
	[UpdatedBy] [varchar](50) NOT NULL DEFAULT (suser_name()),
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[UserAccountMeterGroup]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[UserAccountMeterGroup](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
	[MeterGroupID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[UserDashSettings]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[UserDashSettings](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[UserAccountID] [uniqueidentifier] NOT NULL,
	[Name] [nvarchar](500) NOT NULL,
	[Value] [nvarchar](500) NOT NULL,
	[Enabled] [bit] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[VoltageCurve]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[VoltageCurve](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[VoltageCurvePoint]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[VoltageCurvePoint](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[VoltageCurveID] [int] NOT NULL,
	[PerUnitMagnitude] [float] NOT NULL,
	[DurationSeconds] [float] NOT NULL,
	[LoadOrder] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[VoltageEnvelope]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[VoltageEnvelope](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
	[Description] [varchar](max) NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[VoltageEnvelopeCurve]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[VoltageEnvelopeCurve](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[VoltageEnvelopeID] [int] NOT NULL,
	[VoltageCurveID] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[WorkbenchFilter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[WorkbenchFilter](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](50) NOT NULL,
	[UserID] [uniqueidentifier] NOT NULL,
	[TimeRange] [varchar](512) NOT NULL,
	[Meters] [varchar](max) NULL,
	[Lines] [varchar](max) NULL,
	[EventTypes] [varchar](50) NOT NULL,
	[IsDefault] [bit] NOT NULL
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[WorkbenchVoltageCurve]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[WorkbenchVoltageCurve](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
	[Visible] [bit] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  Table [dbo].[WorkbenchVoltageCurvePoint]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[WorkbenchVoltageCurvePoint](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[VoltageCurveID] [int] NOT NULL,
	[PerUnitMagnitude] [float] NOT NULL,
	[DurationSeconds] [float] NOT NULL,
	[LoadOrder] [int] NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO
/****** Object:  Table [dbo].[XSLTemplate]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING OFF
GO
CREATE TABLE [dbo].[XSLTemplate](
	[ID] [int] IDENTITY(1,1) NOT NULL,
	[Name] [varchar](200) NOT NULL,
	[Template] [varchar](max) NOT NULL,
PRIMARY KEY CLUSTERED 
(
	[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]

GO
SET ANSI_PADDING OFF
GO
/****** Object:  View [dbo].[ActiveMeasurements]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[ActiveMeasurements]
AS
SELECT        'XDA:' + CAST(ROW_NUMBER() OVER (ORDER BY MeterSignal.ID) AS varchar(20)) AS ID, 
			   dbo.MeterSignal.SignalID, 
			   COALESCE(CAST(Meter.ID AS varchar(30)) + '_' + dbo.Meter.Name + '_' + dbo.MeterSignal.Category,(
					CASE 
						WHEN MeterSignal.Category = 'GlobalEvent' THEN CAST(MeterSignal.MeterID AS varchar(30)) + '_' + 'GlobalEvents' + '_' + dbo.MeterSignal.Category
					END
			   )) AS PointTag, 
			   dbo.MeterSignal.Category
FROM            dbo.MeterSignal Left  JOIN
                         dbo.Meter ON dbo.Meter.ID = dbo.MeterSignal.MeterID


GO
/****** Object:  View [dbo].[AlarmRangeLimitView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[AlarmRangeLimitView]
AS
SELECT
    AlarmRangeLimit.ID,
    AlarmRangeLimit.ChannelID,
    Channel.MeterID,
    Channel.LineID,
    Channel.Name,
    AlarmRangeLimit.AlarmTypeID,
    AlarmRangeLimit.Severity,
    AlarmRangeLimit.High,
    AlarmRangeLimit.Low,
    AlarmRangeLimit.RangeInclusive,
    AlarmRangeLimit.PerUnit,
    AlarmRangeLimit.Enabled,
    MeasurementType.Name AS MeasurementType,
    MeasurementCharacteristic.Name AS MeasurementCharacteristic,
    Phase.Name AS Phase,
    Channel.HarmonicGroup,
    Channel.MeasurementTypeID,
    Channel.MeasurementCharacteristicID,
    Channel.PhaseID,
    AlarmRangeLimit.IsDefault,
    Meter.Name AS MeterName
FROM
    AlarmRangeLimit JOIN
    Channel ON AlarmRangeLimit.ChannelID = Channel.ID JOIN
    MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
    MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
    Phase ON Channel.PhaseID = Phase.ID JOIN
    Meter ON Channel.MeterID = Meter.ID

GO
/****** Object:  View [dbo].[AuditLogView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[AuditLogView]
AS
SELECT        TOP (2000) ID, TableName, PrimaryKeyColumn, PrimaryKeyValue, ColumnName, OriginalValue, NewValue, Deleted, UpdatedBy, UpdatedOn
FROM            dbo.AuditLog
WHERE         UpdatedBy IS NOT NULL

GO
/****** Object:  View [dbo].[Breaker]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[Breaker] AS
SELECT
	SUBSTRING(BreakerNum, PATINDEX('%[^0]%', BreakerNum + '.'), LEN(BreakerNum)) AS AssetKey,
	BreakerSpeed AS Speed
FROM MaximoBreaker
GO
/****** Object:  View [dbo].[BreakerView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[BreakerView]
AS
SELECT        dbo.BreakerOperation.ID, dbo.Meter.ID AS MeterID, dbo.Event.ID AS EventID, dbo.EventType.Name AS EventType, dbo.BreakerOperation.TripCoilEnergized AS Energized, dbo.BreakerOperation.BreakerNumber, 
                         dbo.MeterLine.LineName, dbo.Phase.Name AS PhaseName, CAST(dbo.BreakerOperation.BreakerTiming AS DECIMAL(16, 5)) AS Timing, dbo.BreakerOperation.BreakerSpeed AS Speed, 
                         dbo.BreakerOperation.UpdatedBy, dbo.BreakerOperationType.Name AS OperationType
FROM            dbo.BreakerOperation INNER JOIN
                         dbo.Event ON dbo.BreakerOperation.EventID = dbo.Event.ID INNER JOIN
                         dbo.EventType ON dbo.EventType.ID = dbo.Event.EventTypeID INNER JOIN
                         dbo.Meter ON dbo.Meter.ID = dbo.Event.MeterID INNER JOIN
                         dbo.Line ON dbo.Line.ID = dbo.Event.LineID INNER JOIN
                         dbo.MeterLine ON dbo.MeterLine.LineID = dbo.Event.LineID AND dbo.MeterLine.MeterID = dbo.Meter.ID INNER JOIN
                         dbo.BreakerOperationType ON dbo.BreakerOperation.BreakerOperationTypeID = dbo.BreakerOperationType.ID INNER JOIN
                         dbo.Phase ON dbo.BreakerOperation.PhaseID = dbo.Phase.ID


GO
/****** Object:  View [dbo].[ChannelDetail]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[ChannelDetail]
AS
SELECT
    Channel.ID,
    Channel.MeterID,
    Meter.AssetKey AS MeterKey,
    Meter.Name AS MeterName,
    Channel.LineID,
    Line.AssetKey AS LineKey,
    MeterLine.LineName,
    Channel.MeasurementTypeID,
    MeasurementType.Name AS MeasurementType,
    Channel.MeasurementCharacteristicID,
    MeasurementCharacteristic.Name AS MeasurementCharacteristic,
    Channel.PhaseID,
    Phase.Name AS Phase,
    Channel.Name,
    Channel.SamplesPerHour,
    Channel.PerUnitValue,
    Channel.HarmonicGroup,
    Series.SourceIndexes AS Mapping,
    Channel.Description,
    Channel.Enabled,
    Series.SeriesTypeID,
    SeriesType.Name AS SeriesType
FROM
    Channel JOIN
    Meter ON Channel.MeterID = Meter.ID JOIN
    Line ON Channel.LineID = Line.ID JOIN
    MeterLine ON
        MeterLine.MeterID = Meter.ID AND
        MeterLine.LineID = Line.ID JOIN
    MeasurementType ON Channel.MeasurementTypeID = MeasurementType.ID JOIN
    MeasurementCharacteristic ON Channel.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
    Phase ON Channel.PhaseID = Phase.ID LEFT OUTER JOIN
    Series ON
        Series.ChannelID = Channel.ID AND
        Series.SourceIndexes <> '' LEFT OUTER JOIN
    SeriesType ON dbo.Series.SeriesTypeID = dbo.SeriesType.ID

GO
/****** Object:  View [dbo].[ChannelsForEvent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[ChannelsForEvent]
AS
SELECT        dbo.Event.ID AS EventID, dbo.Series.SourceIndexes AS Mapping, dbo.Channel.Name AS ChannelName, dbo.Channel.ID AS ChannelID
FROM            dbo.Event INNER JOIN
                         dbo.Channel ON dbo.Event.MeterID = dbo.Channel.MeterID AND dbo.Event.LineID = dbo.Channel.LineID INNER JOIN
                         dbo.Series ON dbo.Channel.ID = dbo.Series.ChannelID


GO
/****** Object:  View [dbo].[ChannelsWithHourlyLimits]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[ChannelsWithHourlyLimits]
AS
SELECT        dbo.Channel.Name, COUNT(DISTINCT dbo.HourOfWeekLimit.HourOfWeek) AS Limits, dbo.Channel.ID, dbo.Channel.MeterID, dbo.AlarmType.Name AS AlarmTypeName, 
                         dbo.MeasurementCharacteristic.Name AS MeasurementCharacteristic, dbo.MeasurementType.Name AS MeasurementType, dbo.Channel.HarmonicGroup, dbo.Phase.Name AS Phase
FROM            dbo.HourOfWeekLimit INNER JOIN
                         dbo.Channel ON dbo.HourOfWeekLimit.ChannelID = dbo.Channel.ID INNER JOIN
                         dbo.AlarmType ON dbo.HourOfWeekLimit.AlarmTypeID = dbo.AlarmType.ID INNER JOIN
                         dbo.Meter ON dbo.Channel.MeterID = dbo.Meter.ID INNER JOIN
                         dbo.MeasurementCharacteristic ON dbo.Channel.MeasurementCharacteristicID = dbo.MeasurementCharacteristic.ID INNER JOIN
                         dbo.MeasurementType ON dbo.Channel.MeasurementTypeID = dbo.MeasurementType.ID INNER JOIN
                         dbo.Phase ON dbo.Channel.PhaseID = dbo.Phase.ID
GROUP BY dbo.Channel.Name, dbo.Channel.MeterID, dbo.Channel.ID, dbo.AlarmType.Name, dbo.MeasurementCharacteristic.Name, dbo.MeasurementType.Name, dbo.Channel.HarmonicGroup, dbo.Phase.Name

GO
/****** Object:  View [dbo].[ChannelsWithNormalLimits]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[ChannelsWithNormalLimits]
AS
SELECT        dbo.Channel.Name, dbo.Channel.ID, dbo.Channel.MeterID, dbo.AlarmType.Name AS AlarmTypeName, 
                         dbo.MeasurementCharacteristic.Name AS MeasurementCharacteristic, dbo.MeasurementType.Name AS MeasurementType, dbo.Channel.HarmonicGroup, dbo.Phase.Name AS Phase, High, Low
FROM            dbo.AlarmRangeLimit INNER JOIN
                         dbo.Channel ON dbo.AlarmRangeLimit.ChannelID = dbo.Channel.ID INNER JOIN
                         dbo.AlarmType ON dbo.AlarmRangeLimit.AlarmTypeID = dbo.AlarmType.ID INNER JOIN
                         dbo.Meter ON dbo.Channel.MeterID = dbo.Meter.ID INNER JOIN
                         dbo.MeasurementCharacteristic ON dbo.Channel.MeasurementCharacteristicID = dbo.MeasurementCharacteristic.ID INNER JOIN
                         dbo.MeasurementType ON dbo.Channel.MeasurementTypeID = dbo.MeasurementType.ID INNER JOIN
                         dbo.Phase ON dbo.Channel.PhaseID = dbo.Phase.ID

GO
/****** Object:  View [dbo].[ContourChannel]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[ContourChannel]
AS
SELECT
    ContourColorScale.ID AS ContourColorScaleID,
    ContourColorScale.Name AS ContourColorScaleName,
    Channel.MeterID AS MeterID,
    Channel.ID AS ChannelID,
    Channel.PerUnitValue
FROM
    ContourColorScale JOIN
    ContourChannelType ON ContourChannelType.ContourColorScaleID = ContourColorScale.ID JOIN
    Channel ON
        Channel.MeasurementTypeID = ContourChannelType.MeasurementTypeID AND
        Channel.MeasurementCharacteristicID = ContourChannelType.MeasurementCharacteristicID AND
        Channel.PhaseID = ContourChannelType.PhaseID AND
        Channel.HarmonicGroup = ContourChannelType.HarmonicGroup

GO
/****** Object:  View [dbo].[DefaultAlarmRangeLimitView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[DefaultAlarmRangeLimitView]
AS
SELECT
    DefaultAlarmRangeLimit.ID,
    DefaultAlarmRangeLimit.MeasurementTypeID,
    DefaultAlarmRangeLimit.AlarmTypeID,
    DefaultAlarmRangeLimit.MeasurementCharacteristicID, 
    DefaultAlarmRangeLimit.Severity,
    DefaultAlarmRangeLimit.High,
    DefaultAlarmRangeLimit.Low,
    DefaultAlarmRangeLimit.PerUnit,
    DefaultAlarmRangeLimit.RangeInclusive, 
    AlarmType.Name AS AlarmType,
    MeasurementCharacteristic.Name AS MeasurementCharacteristic,
    MeasurementType.Name AS MeasurementType
FROM
    DefaultAlarmRangeLimit JOIN
    AlarmType ON DefaultAlarmRangeLimit.AlarmTypeID = AlarmType.ID JOIN
    MeasurementCharacteristic ON DefaultAlarmRangeLimit.MeasurementCharacteristicID = MeasurementCharacteristic.ID JOIN
    MeasurementType ON DefaultAlarmRangeLimit.MeasurementTypeID = MeasurementType.ID

GO
/****** Object:  View [dbo].[DisturbanceView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[DisturbanceView]
AS
SELECT dbo.Disturbance.ID, dbo.Disturbance.EventID, dbo.Disturbance.EventTypeID, dbo.Disturbance.PhaseID, dbo.Disturbance.Magnitude, dbo.Disturbance.PerUnitMagnitude, dbo.Disturbance.StartTime, 
       dbo.Disturbance.EndTime, dbo.Disturbance.DurationSeconds, dbo.Disturbance.DurationCycles, dbo.Disturbance.StartIndex, dbo.Disturbance.EndIndex, dbo.Event.MeterID,
           (SELECT        MAX(SeverityCode) AS Expr1
             FROM            dbo.DisturbanceSeverity
             WHERE        (DisturbanceID = dbo.Disturbance.ID)) AS SeverityCode, dbo.Meter.Name AS MeterName, dbo.Phase.Name AS PhaseName, dbo.Event.LineID
FROM   dbo.Disturbance INNER JOIN
       dbo.Event ON dbo.Disturbance.EventID = dbo.Event.ID INNER JOIN
       dbo.Meter ON dbo.Event.MeterID = dbo.Meter.ID INNER JOIN
       dbo.Phase ON dbo.Disturbance.PhaseID = dbo.Phase.ID

GO
/****** Object:  View [dbo].[EmailGroupLineGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[EmailGroupLineGroupView]
AS
SELECT        dbo.EmailGroupLineGroup.ID, dbo.EmailGroupLineGroup.EmailGroupID, dbo.EmailGroupLineGroup.LineGroupID, dbo.EmailGroup.Name AS EmailGroup, dbo.LineGroup.Name AS LineGroup
FROM            dbo.EmailGroupLineGroup INNER JOIN
                         dbo.EmailGroup ON dbo.EmailGroupLineGroup.EmailGroupID = dbo.EmailGroup.ID INNER JOIN
                         dbo.LineGroup ON dbo.EmailGroupLineGroup.LineGroupID = dbo.LineGroup.ID


GO
/****** Object:  View [dbo].[EmailGroupMeterGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[EmailGroupMeterGroupView]
AS
SELECT        dbo.EmailGroupMeterGroup.ID, dbo.EmailGroupMeterGroup.EmailGroupID, dbo.EmailGroupMeterGroup.MeterGroupID, dbo.EmailGroup.Name AS EmailGroup, dbo.MeterGroup.Name AS MeterGroup
FROM            dbo.EmailGroupMeterGroup INNER JOIN
                         dbo.EmailGroup ON dbo.EmailGroupMeterGroup.EmailGroupID = dbo.EmailGroup.ID INNER JOIN
                         dbo.MeterGroup ON dbo.EmailGroupMeterGroup.MeterGroupID = dbo.MeterGroup.ID


GO
/****** Object:  View [dbo].[EmailGroupTypeView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[EmailGroupTypeView]
AS
SELECT        dbo.EmailGroupType.ID, dbo.EmailGroupType.EmailGroupID, dbo.EmailGroupType.EmailTypeID, dbo.EmailGroup.Name AS GroupName, 
                         dbo.EmailCategory.Name + ' - ' + dbo.XSLTemplate.Name AS TypeName
FROM            dbo.EmailGroupType INNER JOIN
                         dbo.EmailGroup ON dbo.EmailGroupType.EmailGroupID = dbo.EmailGroup.ID INNER JOIN
                         dbo.EmailType ON dbo.EmailGroupType.EmailTypeID = dbo.EmailType.ID INNER JOIN
                         dbo.XSLTemplate ON dbo.XSLTemplate.ID = dbo.EmailType.XSLTemplateID INNER JOIN
                         dbo.EmailCategory ON dbo.EmailCategory.ID = dbo.EmailType.EmailCategoryID


GO
/****** Object:  View [dbo].[EmailGroupUserAccountView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[EmailGroupUserAccountView] AS
SELECT
    EmailGroupUserAccount.ID,
    EmailGroupUserAccount.EmailGroupID,
    EmailGroupUserAccount.UserAccountID,
    EmailGroup.Name AS EmailGroup,
    COALESCE(UserAccount.FirstName + ' ' + UserAccount.LastName, UserAccount.FirstName, UserAccount.Name) AS UserName
FROM
    EmailGroupUserAccount JOIN
    EmailGroup ON EmailGroupUserAccount.EmailGroupID = EmailGroup.ID JOIN
    UserAccount ON EmailGroupUserAccount.UserAccountID = UserAccount.ID

GO
/****** Object:  View [dbo].[EmailGroupUserGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[EmailGroupUserGroupView]
AS
SELECT        dbo.EmailGroupUserAccount.ID, dbo.EmailGroupUserAccount.EmailGroupID, dbo.EmailGroupUserAccount.UserAccountID, dbo.EmailGroup.Name AS EmailGroup, 
                         dbo.UserAccount.FirstName + ' ' + dbo.UserAccount.LastName AS UserName
FROM            dbo.EmailGroupUserAccount INNER JOIN
                         dbo.EmailGroup ON dbo.EmailGroupUserAccount.EmailGroupID = dbo.EmailGroup.ID INNER JOIN
                         dbo.UserAccount ON dbo.EmailGroupUserAccount.UserAccountID = dbo.UserAccount.ID


GO
/****** Object:  View [dbo].[EmailTypeView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[EmailTypeView]
AS
SELECT        dbo.EmailType.EmailCategoryID, dbo.EmailType.XSLTemplateID, dbo.EmailType.ID, dbo.EmailCategory.Name AS EmailCategory, dbo.XSLTemplate.Name AS XSLTemplate, 
                         dbo.EmailCategory.Name + ' - ' + dbo.XSLTemplate.Name AS Name
FROM            dbo.EmailType INNER JOIN
                         dbo.EmailCategory ON dbo.EmailType.EmailCategoryID = dbo.EmailCategory.ID INNER JOIN
                         dbo.XSLTemplate ON dbo.EmailType.XSLTemplateID = dbo.XSLTemplate.ID


GO
/****** Object:  View [dbo].[EventView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[EventView]
AS
SELECT
    Event.ID,
    Event.FileGroupID,
    Event.MeterID,
    Event.LineID,
    Event.EventTypeID,
    Event.EventDataID,
    Event.Name,
    Event.Alias,
    Event.ShortName,
    Event.StartTime,
    Event.EndTime,
    Event.Samples,
    Event.TimeZoneOffset,
    Event.SamplesPerSecond,
    Event.SamplesPerCycle,
    Event.Description,
    Event.UpdatedBy,
    MeterLine.LineName,
    Meter.Name AS MeterName,
    MeterLocation.Name AS StationName,
    Line.Length,
    EventType.Name AS EventTypeName
FROM
    Event JOIN
    Meter ON Event.MeterID = Meter.ID JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
    Line ON Event.LineID = Line.ID JOIN
    MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Line.ID JOIN
    EventType ON Event.EventTypeID = EventType.ID

GO
/****** Object:  View [dbo].[FaultView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[FaultView]
AS
SELECT
            FaultSummary.ID AS ID,
			FaultSummary.EventID,
			FaultSummary.Algorithm,
			FaultSummary.FaultNumber,
			FaultSummary.CalculationCycle,
			FaultSummary.Distance,
			FaultSummary.CurrentMagnitude,
			FaultSummary.CurrentLag,
			FaultSummary.PrefaultCurrent,
			FaultSummary.PostfaultCurrent,
			FaultSummary.Inception,
			FaultSummary.DurationSeconds,
			FaultSummary.DurationCycles,
			FaultSummary.FaultType,
			FaultSummary.IsSelectedAlgorithm,
			FaultSummary.IsValid,
			FaultSummary.IsSuppressed,
            Meter.Name AS MeterName,
            Meter.ShortName AS ShortName,
            MeterLocation.ShortName AS LocationName,
            Meter.ID AS MeterID,
            Line.ID AS LineID,
            MeterLine.LineName AS LineName,
            Line.VoltageKV AS Voltage,
            Event.StartTime AS InceptionTime,
    CASE WHEN FaultSummary.Distance = '-1E308' THEN 'NaN' ELSE CAST(CAST(FaultSummary.Distance AS DECIMAL(16,2)) AS NVARCHAR(19)) END AS CurrentDistance,
    ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY FaultSummary.IsSuppressed, FaultSummary.IsSelectedAlgorithm DESC, FaultSummary.Inception) AS RK
FROM
    FaultSummary JOIN
    Event ON FaultSummary.EventID = Event.ID JOIN
    EventType ON Event.EventTypeID = EventType.ID JOIN
    Meter ON Event.MeterID = Meter.ID JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
    Line ON Event.LineID = Line.ID JOIN
    MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Line.ID
WHERE
    EventType.Name = 'Fault'

GO
/****** Object:  View [dbo].[GroupMeterView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[GroupMeterView]
AS
SELECT
    GroupMeter.MeterID,
    GroupMeter.GroupID,
    GroupMeter.ID,
    Meter.Name AS MeterName,
    MeterLocation.Name AS Location
FROM
    GroupMeter JOIN
    Meter ON GroupMeter.MeterID = Meter.ID JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID


GO
/****** Object:  View [dbo].[HourOfWeekLimitView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[HourOfWeekLimitView]
AS
SELECT        dbo.HourOfWeekLimit.ID, dbo.HourOfWeekLimit.ChannelID, dbo.HourOfWeekLimit.AlarmTypeID, dbo.HourOfWeekLimit.HourOfWeek, dbo.HourOfWeekLimit.Severity, dbo.HourOfWeekLimit.High, dbo.HourOfWeekLimit.Low, 
                         dbo.HourOfWeekLimit.Enabled, dbo.AlarmType.Name AS AlarmTypeName
FROM            dbo.HourOfWeekLimit INNER JOIN
                         dbo.AlarmType ON dbo.HourOfWeekLimit.AlarmTypeID = dbo.AlarmType.ID

GO
/****** Object:  View [dbo].[LineLineGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[LineLineGroupView]
AS
SELECT
    LineLineGroup.ID,
    Line.AssetKey AS LineName,
    (SELECT TOP 1 LineName FROM MeterLine Where LineID = Line.ID) AS LongLineName,
    Line.ID AS LineID,
    LineGroupID
FROM
    LineLineGroup JOIN
    Line ON LineLineGroup.LineID = Line.ID

GO
/****** Object:  View [dbo].[LineView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[LineView]
AS
SELECT
    Line.ID,
    Line.AssetKey,
    Line.VoltageKV,
    Line.ThermalRating,
    Line.Length,
    Line.Description,
    (
        SELECT TOP 1 LineName
        FROM MeterLine
        WHERE LineID = Line.ID
    ) AS TopName,
    LineImpedance.R0,
    LineImpedance.X0,
    LineImpedance.R1,
    LineImpedance.X1,
    LineImpedance.ID AS LineImpedanceID
FROM
    Line LEFT OUTER JOIN
    LineImpedance ON Line.ID = LineImpedance.LineID

GO
/****** Object:  View [dbo].[MeterDetail]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[MeterDetail]
AS
SELECT
    Meter.ID,
    Meter.AssetKey,
    Meter.MeterLocationID,
    MeterLocation.AssetKey AS LocationKey,
    MeterLocation.Name AS Location,
    MeterLocation.Latitude,
    MeterLocation.Longitude,
    Meter.Name,
    Meter.Alias,
    Meter.ShortName,
    Meter.Make,
    Meter.Model,
    CASE COALESCE(Meter.TimeZone, '')
        WHEN '' THEN COALESCE(Setting.Value, 'UTC')
        ELSE Meter.TimeZone
    END AS TimeZone,
    Meter.Description
FROM
    Meter JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
    Setting ON Setting.Name = 'DefaultMeterTimeZone'

GO
/****** Object:  View [dbo].[MeterLineDetail]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[MeterLineDetail]
AS
SELECT
    MeterLine.ID,
    MeterLine.MeterID,
    Meter.AssetKey AS MeterKey,
    Meter.Name AS MeterName,
    MeterLine.LineID,
    Line.AssetKey AS LineKey,
    MeterLine.LineName
FROM
    MeterLine JOIN
    Meter ON MeterLine.MeterID = Meter.ID JOIN
    Line ON MeterLIne.LineID = Line.ID

GO
/****** Object:  View [dbo].[MeterMeterGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[MeterMeterGroupView]
AS
SELECT
    MeterMeterGroup.ID,
    Meter.Name AS MeterName,
    Meter.ID AS MeterID,
    MeterGroupID,
    MeterLocation.Name AS Location
FROM
    MeterMeterGroup JOIN
    Meter ON MeterMeterGroup.MeterID = Meter.ID JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID

GO
/****** Object:  View [dbo].[MetersWithHourlyLimits]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[MetersWithHourlyLimits]
AS
SELECT        dbo.Meter.Name, COUNT(DISTINCT dbo.Channel.ID) AS Limits, dbo.Meter.ID
FROM            dbo.HourOfWeekLimit INNER JOIN
                         dbo.Channel ON dbo.HourOfWeekLimit.ChannelID = dbo.Channel.ID INNER JOIN
                         dbo.Meter ON dbo.Channel.MeterID = dbo.Meter.ID
GROUP BY dbo.Meter.Name, dbo.Meter.ID

GO
/****** Object:  View [dbo].[MetersWithNormalLimits]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[MetersWithNormalLimits]
AS
SELECT        dbo.Meter.Name, COUNT(DISTINCT dbo.Channel.ID) AS Limits, dbo.Meter.ID
FROM            dbo.AlarmRangeLimit INNER JOIN
                         dbo.Channel ON dbo.AlarmRangeLimit.ChannelID = dbo.Channel.ID INNER JOIN
                         dbo.Meter ON dbo.Channel.MeterID = dbo.Meter.ID
GROUP BY dbo.Meter.Name, dbo.Meter.ID

GO
/****** Object:  View [dbo].[ReproccessEvent]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[ReproccessEvent]
AS
SELECT DISTINCT FileGroupID, MeterID
FROM            dbo.Event


GO
/****** Object:  View [dbo].[UserAccountMeterGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[UserAccountMeterGroupView]
AS
SELECT
    UserAccountMeterGroup.ID,
    UserAccountMeterGroup.UserAccountID,
    UserAccountMeterGroup.MeterGroupID,
    UserAccount.Name AS Username,
    MeterGroup.Name AS GroupName
FROM
    UserAccountMeterGroup JOIN
    UserAccount ON UserAccountMeterGroup.UserAccountID = UserAccount.ID JOIN
    MeterGroup ON UserAccountMeterGroup.MeterGroupID = MeterGroup.ID

GO
/****** Object:  View [dbo].[UserGroupView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[UserGroupView]
AS
SELECT        dbo.UserGroup.ID, dbo.UserGroup.UserID, dbo.UserGroup.GroupID, dbo.[User].Name AS Username, dbo.[User].Active, dbo.[Group].GroupName
FROM            dbo.UserGroup INNER JOIN
                         dbo.[User] ON dbo.UserGroup.UserID = dbo.[User].ID INNER JOIN
                         dbo.[Group] ON dbo.UserGroup.GroupID = dbo.[Group].ID


GO
/****** Object:  View [dbo].[UserMeter]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

CREATE VIEW [dbo].[UserMeter]
AS
SELECT DISTINCT
    UserAccount.Name AS UserName,
    Meter.ID AS MeterID
FROM
    Meter JOIN
    MeterMeterGroup ON MeterMeterGroup.MeterID = Meter.ID JOIN
    UserAccountMeterGroup ON MeterMeterGroup.MeterGroupID = UserAccountMeterGroup.MeterGroupID JOIN
    UserAccount ON UserAccountMeterGroup.UserAccountID = UserAccount.ID


GO
/****** Object:  View [dbo].[WorkbenchVoltageCurveView]    Script Date: 11/13/2017 5:07:13 PM ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE VIEW [dbo].[WorkbenchVoltageCurveView]
AS
SELECT	dbo.WorkbenchVoltageCurve.ID, dbo.WorkbenchVoltageCurve.Name, dbo.WorkbenchVoltageCurvePoint.ID AS CurvePointID, dbo.WorkbenchVoltageCurvePoint.PerUnitMagnitude, 
		dbo.WorkbenchVoltageCurvePoint.DurationSeconds, dbo.WorkbenchVoltageCurvePoint.LoadOrder, dbo.WorkbenchVoltageCurve.Visible
FROM	dbo.WorkbenchVoltageCurve INNER JOIN
		dbo.WorkbenchVoltageCurvePoint ON dbo.WorkbenchVoltageCurve.ID = dbo.WorkbenchVoltageCurvePoint.VoltageCurveID AND 
		dbo.WorkbenchVoltageCurve.ID = dbo.WorkbenchVoltageCurvePoint.VoltageCurveID AND dbo.WorkbenchVoltageCurve.ID = dbo.WorkbenchVoltageCurvePoint.VoltageCurveID

GO
ALTER TABLE [dbo].[ContourAnimation] ADD  DEFAULT (getutcdate()) FOR [AccessedOn]
GO
ALTER TABLE [dbo].[AlarmEmailCriterion]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[AlarmEmailCriterion]  WITH CHECK ADD FOREIGN KEY([MeasurementTypeID])
REFERENCES [dbo].[MeasurementType] ([ID])
GO
ALTER TABLE [dbo].[AlarmEmailCriterion]  WITH CHECK ADD FOREIGN KEY([MeasurementCharacteristicID])
REFERENCES [dbo].[MeasurementCharacteristic] ([ID])
GO
ALTER TABLE [dbo].[ApplicationRoleSecurityGroup]  WITH CHECK ADD FOREIGN KEY([ApplicationRoleID])
REFERENCES [dbo].[ApplicationRole] ([ID])
GO
ALTER TABLE [dbo].[ApplicationRoleSecurityGroup]  WITH CHECK ADD FOREIGN KEY([SecurityGroupID])
REFERENCES [dbo].[SecurityGroup] ([ID])
GO
ALTER TABLE [dbo].[ApplicationRoleUserAccount]  WITH CHECK ADD FOREIGN KEY([ApplicationRoleID])
REFERENCES [dbo].[ApplicationRole] ([ID])
GO
ALTER TABLE [dbo].[ApplicationRoleUserAccount]  WITH CHECK ADD FOREIGN KEY([UserAccountID])
REFERENCES [dbo].[UserAccount] ([ID])
GO
ALTER TABLE [dbo].[BreakerEmailCriterion]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[ChannelAlarmSummary]  WITH CHECK ADD FOREIGN KEY([AlarmTypeID])
REFERENCES [dbo].[AlarmType] ([ID])
GO
ALTER TABLE [dbo].[ChannelAlarmSummary]  WITH CHECK ADD FOREIGN KEY([ChannelID])
REFERENCES [dbo].[Channel] ([ID])
GO
ALTER TABLE [dbo].[ContourAnimationFrame]  WITH CHECK ADD FOREIGN KEY([ContourAnimationID])
REFERENCES [dbo].[ContourAnimation] ([ID])
GO
ALTER TABLE [dbo].[ContourChannelType]  WITH CHECK ADD FOREIGN KEY([ContourColorScaleID])
REFERENCES [dbo].[ContourColorScale] ([ID])
GO
ALTER TABLE [dbo].[ContourChannelType]  WITH CHECK ADD FOREIGN KEY([MeasurementTypeID])
REFERENCES [dbo].[MeasurementType] ([ID])
GO
ALTER TABLE [dbo].[ContourChannelType]  WITH CHECK ADD FOREIGN KEY([MeasurementCharacteristicID])
REFERENCES [dbo].[MeasurementCharacteristic] ([ID])
GO
ALTER TABLE [dbo].[ContourChannelType]  WITH CHECK ADD FOREIGN KEY([PhaseID])
REFERENCES [dbo].[Phase] ([ID])
GO
ALTER TABLE [dbo].[ContourColorScalePoint]  WITH CHECK ADD FOREIGN KEY([ContourColorScaleID])
REFERENCES [dbo].[ContourColorScale] ([ID])
GO
ALTER TABLE [dbo].[DisturbanceEmailCriterion]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[DisturbanceSeverity]  WITH CHECK ADD FOREIGN KEY([DisturbanceID])
REFERENCES [dbo].[Disturbance] ([ID])
GO
ALTER TABLE [dbo].[DisturbanceSeverity]  WITH CHECK ADD FOREIGN KEY([VoltageEnvelopeID])
REFERENCES [dbo].[VoltageEnvelope] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupLineGroup]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupLineGroup]  WITH CHECK ADD FOREIGN KEY([LineGroupID])
REFERENCES [dbo].[LineGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupMeterGroup]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupMeterGroup]  WITH CHECK ADD FOREIGN KEY([MeterGroupID])
REFERENCES [dbo].[MeterGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupSecurityGroup]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupSecurityGroup]  WITH CHECK ADD FOREIGN KEY([SecurityGroupID])
REFERENCES [dbo].[SecurityGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupType]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupType]  WITH CHECK ADD FOREIGN KEY([EmailTypeID])
REFERENCES [dbo].[EmailType] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupUserAccount]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[EmailGroupUserAccount]  WITH CHECK ADD FOREIGN KEY([UserAccountID])
REFERENCES [dbo].[UserAccount] ([ID])
GO
ALTER TABLE [dbo].[EmailType]  WITH CHECK ADD FOREIGN KEY([EmailCategoryID])
REFERENCES [dbo].[EmailCategory] ([ID])
GO
ALTER TABLE [dbo].[EmailType]  WITH CHECK ADD FOREIGN KEY([XSLTemplateID])
REFERENCES [dbo].[XSLTemplate] ([ID])
GO
ALTER TABLE [dbo].[EventNote]  WITH CHECK ADD FOREIGN KEY([EventID])
REFERENCES [dbo].[Event] ([ID])
GO
ALTER TABLE [dbo].[EventSentEmail]  WITH CHECK ADD FOREIGN KEY([EventID])
REFERENCES [dbo].[Event] ([ID])
GO
ALTER TABLE [dbo].[EventSentEmail]  WITH CHECK ADD FOREIGN KEY([SentEmailID])
REFERENCES [dbo].[SentEmail] ([ID])
GO
ALTER TABLE [dbo].[FaultCurveStatistic]  WITH CHECK ADD FOREIGN KEY([FaultCurveID])
REFERENCES [dbo].[FaultCurve] ([ID])
GO
ALTER TABLE [dbo].[FaultEmailCriterion]  WITH CHECK ADD FOREIGN KEY([EmailGroupID])
REFERENCES [dbo].[EmailGroup] ([ID])
GO
ALTER TABLE [dbo].[FaultNote]  WITH CHECK ADD FOREIGN KEY([UserAccountID])
REFERENCES [dbo].[UserAccount] ([ID])
GO
ALTER TABLE [dbo].[FileGroupLocalToRemote]  WITH CHECK ADD FOREIGN KEY([LocalFileGroupID])
REFERENCES [dbo].[FileGroup] ([ID])
GO
ALTER TABLE [dbo].[LineLineGroup]  WITH CHECK ADD FOREIGN KEY([LineGroupID])
REFERENCES [dbo].[LineGroup] ([ID])
GO
ALTER TABLE [dbo].[LineLineGroup]  WITH CHECK ADD FOREIGN KEY([LineID])
REFERENCES [dbo].[Line] ([ID])
GO
ALTER TABLE [dbo].[MeterAlarmSummary]  WITH CHECK ADD FOREIGN KEY([AlarmTypeID])
REFERENCES [dbo].[AlarmType] ([ID])
GO
ALTER TABLE [dbo].[MeterAlarmSummary]  WITH CHECK ADD FOREIGN KEY([MeterID])
REFERENCES [dbo].[Meter] ([ID])
GO
ALTER TABLE [dbo].[MeterMeterGroup]  WITH CHECK ADD FOREIGN KEY([MeterID])
REFERENCES [dbo].[Meter] ([ID])
GO
ALTER TABLE [dbo].[MeterMeterGroup]  WITH CHECK ADD FOREIGN KEY([MeterGroupID])
REFERENCES [dbo].[MeterGroup] ([ID])
GO
ALTER TABLE [dbo].[PQMarkAggregate]  WITH CHECK ADD FOREIGN KEY([MeterID])
REFERENCES [dbo].[Meter] ([ID])
GO
ALTER TABLE [dbo].[PQMarkCompanyMeter]  WITH CHECK ADD FOREIGN KEY([MeterID])
REFERENCES [dbo].[Meter] ([ID])
GO
ALTER TABLE [dbo].[PQMarkCompanyMeter]  WITH CHECK ADD FOREIGN KEY([PQMarkCompanyID])
REFERENCES [dbo].[PQMarkCompany] ([ID])
GO
ALTER TABLE [dbo].[RemoteXDAInstanceMeter]  WITH CHECK ADD FOREIGN KEY([MetersToDataPushID])
REFERENCES [dbo].[MetersToDataPush] ([ID])
GO
ALTER TABLE [dbo].[RemoteXDAInstanceMeter]  WITH CHECK ADD FOREIGN KEY([RemoteXDAInstanceID])
REFERENCES [dbo].[RemoteXDAInstance] ([ID])
GO
ALTER TABLE [dbo].[SecurityGroupUserAccount]  WITH CHECK ADD FOREIGN KEY([SecurityGroupID])
REFERENCES [dbo].[SecurityGroup] ([ID])
GO
ALTER TABLE [dbo].[SecurityGroupUserAccount]  WITH CHECK ADD FOREIGN KEY([UserAccountID])
REFERENCES [dbo].[UserAccount] ([ID])
GO
ALTER TABLE [dbo].[UserAccountMeterGroup]  WITH CHECK ADD FOREIGN KEY([MeterGroupID])
REFERENCES [dbo].[MeterGroup] ([ID])
GO
ALTER TABLE [dbo].[UserAccountMeterGroup]  WITH CHECK ADD FOREIGN KEY([UserAccountID])
REFERENCES [dbo].[UserAccount] ([ID])
GO
ALTER TABLE [dbo].[VoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[VoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[VoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageEnvelopeID])
REFERENCES [dbo].[VoltageEnvelope] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageEnvelopeID])
REFERENCES [dbo].[VoltageEnvelope] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageEnvelopeID])
REFERENCES [dbo].[VoltageEnvelope] ([ID])
GO
ALTER TABLE [dbo].[VoltageEnvelopeCurve]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[VoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[WorkbenchVoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[WorkbenchVoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[WorkbenchVoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[WorkbenchVoltageCurve] ([ID])
GO
ALTER TABLE [dbo].[WorkbenchVoltageCurvePoint]  WITH CHECK ADD FOREIGN KEY([VoltageCurveID])
REFERENCES [dbo].[WorkbenchVoltageCurve] ([ID])
GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

DROP FUNCTION authMeters
GO

CREATE FUNCTION [authMeters](@username varchar(100))
RETURNS TABLE
AS
RETURN
(
Select distinct MeterID
from UserMeter
where UserName = @username
)

GO


ALTER TABLE Disturbance
ADD UpdatedBy VARCHAR(200) NULL
GO

ALTER TABLE DoubleEndedFaultDistance
ADD UNIQUE NONCLUSTERED(LocalFaultSummaryID)
GO

ALTER TABLE DoubleEndedFaultDistance
ADD UNIQUE NONCLUSTERED(RemoteFaultSummaryID)
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO




ALTER VIEW [EventDetail] AS
WITH TimeTolerance AS
(
    SELECT
        COALESCE(CAST(Value AS FLOAT), 0.5) AS Tolerance
    FROM
        (SELECT 'TimeTolerance' AS Name) AS SettingName LEFT OUTER JOIN
        Setting ON SettingName.Name = Setting.Name
),
SelectedDisturbance AS
(
    SELECT Disturbance.*
    FROM
        Disturbance JOIN
        Phase ON Disturbance.PhaseID = Phase.ID JOIN
        Disturbance WorstDisturbance ON
            Disturbance.EventID = WorstDisturbance.EventID AND
            Disturbance.Magnitude = WorstDisturbance.Magnitude AND
            Disturbance.DurationCycles = WorstDisturbance.DurationCycles JOIN
        Phase WorstPhase ON WorstDisturbance.PhaseID = WorstPhase.ID
    WHERE
        Phase.Name <> 'Worst' AND
        WorstPhase.Name = 'Worst'
),
DisturbanceData AS
(
    SELECT
        SelectedDisturbance.ID AS DisturbanceID,
        Meter.AssetKey AS MeterKey,
        MeterLocation.Name AS StationName,
        MeterLine.LineName,
        EventType.Name AS DisturbanceType,
        Phase.Name AS Phase,
        SelectedDisturbance.StartTime,
        SelectedDisturbance.EndTime,
        SelectedDisturbance.DurationCycles,
        SelectedDisturbance.DurationSeconds * 1000.0 AS DurationMilliseconds,
        SelectedDisturbance.Magnitude,
        SelectedDisturbance.PerUnitMagnitude,
        RIGHT(DataFile.FilePath, CHARINDEX('\', REVERSE(DataFile.FilePath)) - 1) AS FileName,
        SelectedDisturbance.EventID,
        Event.StartTime AS EventStartTime,
        Event.EndTime AS EventEndTime
    FROM
        SelectedDisturbance JOIN
        Event ON SelectedDisturbance.EventID = Event.ID JOIN
        EventType ON SelectedDisturbance.EventTypeID = EventType.ID JOIN
        DataFile ON DataFile.FileGroupID = Event.FileGroupID JOIN
        Meter ON Event.MeterID = Meter.ID JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
        MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Event.LineID JOIN
        Phase ON SelectedDisturbance.PhaseID = Phase.ID
    WHERE
        DataFile.FilePath LIKE '%.DAT' OR
        DataFile.FilePath LIKE '%.D00' OR
        DataFile.FilePath LIKE '%.PQD' OR
        DataFile.FilePath LIKE '%.RCD' OR
        DataFile.FilePath LIKE '%.RCL'
),
SelectedSummary AS
(
    SELECT FaultSummary.*
    FROM
		FaultSummary JOIN
		Event ON FaultSummary.EventID = Event.ID JOIN
		EventType ON Event.EventTypeID = EventType.ID
    WHERE
		IsSelectedAlgorithm <> 0 AND
		EventType.Name = 'Fault'
),
SummaryData AS
(
    SELECT
        SelectedSummary.ID AS FaultSummaryID,
        Meter.AssetKey AS MeterKey,
        MeterLocation.Name AS StationName,
        MeterLine.LineName,
        SelectedSummary.FaultType,
        SelectedSummary.Inception,
        SelectedSummary.DurationCycles,
        SelectedSummary.DurationSeconds * 1000.0 AS DurationMilliseconds,
        SelectedSummary.PrefaultCurrent,
        SelectedSummary.PostfaultCurrent,
        SelectedSummary.CurrentMagnitude AS FaultCurrent,
        SelectedSummary.Algorithm,
        SelectedSummary.Distance AS SingleEndedDistance,
        DoubleEndedFaultSummary.Distance AS DoubleEndedDistance,
        DoubleEndedFaultSummary.Angle AS DoubleEndedAngle,
        RIGHT(DataFile.FilePath, CHARINDEX('\', REVERSE(DataFile.FilePath)) - 1) AS FileName,
        RIGHT(DataFile.FilePath, CHARINDEX(',', REVERSE(DataFile.FilePath)) - 1) AS ShortFileName,
        SelectedSummary.EventID,
        Event.StartTime AS EventStartTime,
        Event.EndTime AS EventEndTime
    FROM
        SelectedSummary JOIN
        Event ON SelectedSummary.EventID = Event.ID JOIN
        DataFile ON DataFile.FileGroupID = Event.FileGroupID JOIN
        Meter ON Event.MeterID = Meter.ID JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
        MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Event.LineID LEFT OUTER JOIN
        DoubleEndedFaultDistance ON DoubleEndedFaultDistance.LocalFaultSummaryID = SelectedSummary.ID LEFT OUTER JOIN
        DoubleEndedFaultSummary ON DoubleEndedFaultSummary.ID = DoubleEndedFaultDistance.ID
    WHERE
        DataFile.FilePath LIKE '%.DAT' OR
        DataFile.FilePath LIKE '%.D00' OR
        DataFile.FilePath LIKE '%.PQD' OR
        DataFile.FilePath LIKE '%.RCD' OR
        DataFile.FilePath LIKE '%.RCL'
),
SummaryIDs AS
(
    SELECT
        SelectedSummary.ID AS FaultSummaryID,
        EventID,
        LineID,
        MeterID AS PartitionID,
        Inception AS OrderID
    FROM
        SelectedSummary JOIN
        Event ON SelectedSummary.EventID = Event.ID
),
SelectedBreakerOperation AS
(
	SELECT BreakerOperation.*
	FROM
		BreakerOperation JOIN
		BreakerOperationType ON BreakerOperation.BreakerOperationTypeID = BreakerOperationType.ID
	WHERE BreakerOperationType.Name = 'Late'
),
BreakerOperationData AS
(
	SELECT
		SelectedBreakerOperation.ID AS BreakerOperationID,
		Meter.AssetKey AS MeterKey,
		MeterLocation.Name AS StationName,
		MeterLine.LineName,
		SelectedBreakerOperation.TripCoilEnergized,
		SelectedBreakerOperation.BreakerNumber,
		Phase.Name AS Phase,
		SelectedBreakerOperation.BreakerTiming,
		SelectedBreakerOperation.StatusTiming,
		SelectedBreakerOperation.DcOffsetDetected,
		SelectedBreakerOperation.BreakerSpeed,
		SelectedBreakerOperation.StatusBitChatter,
        RIGHT(DataFile.FilePath, CHARINDEX('\', REVERSE(DataFile.FilePath)) - 1) AS FileName,
        RIGHT(DataFile.FilePath, CHARINDEX(',', REVERSE(DataFile.FilePath)) - 1) AS ShortFileName,
		SelectedBreakerOperation.EventID,
		Event.StartTime AS EventStartTime,
		Event.EndTime AS EventEndTime
	FROM
		SelectedBreakerOperation JOIN
		Phase ON SelectedBreakerOperation.PhaseID = Phase.ID JOIN
		Event ON SelectedBreakerOperation.EventID = Event.ID JOIN
		DataFile ON DataFile.FileGroupID = Event.FileGroupID JOIN
		Meter ON Event.MeterID = Meter.ID JOIN
		MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
		MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Event.LineID
	WHERE
		DataFile.FilePath LIKE '%.DAT' OR
		DataFile.FilePath LIKE '%.D00' OR
		DataFile.FilePath LIKE '%.PQD' OR
		DataFile.FilePath LIKE '%.RCD' OR
		DataFile.FilePath LIKE '%.RCL'
),
OperationIDs AS
(
    SELECT
        SelectedBreakerOperation.ID AS BreakerOperationID,
        EventID,
        LineID,
        MeterID AS PartitionID,
        TripCoilEnergized AS OrderID
    FROM
        SelectedBreakerOperation JOIN
        Event ON SelectedBreakerOperation.EventID = Event.ID
)
SELECT
    Event.ID AS EventID,
    (
        SELECT
            Event.ID AS [Event/ID],
            Event.StartTime AS [Event/StartTime],
            Event.EndTime AS [Event/EndTime],
            EventType.Name AS [Event/Type],
            (
                SELECT
                    SequenceNumber AS [@num],
                    (
                        SELECT
                            MeterKey,
                            StationName,
                            LineName,
                            DisturbanceType,
                            Phase,
                            StartTime,
                            EndTime,
                            DurationCycles,
                            DurationMilliseconds,
                            Magnitude,
                            PerUnitMagnitude,
                            EventStartTime,
                            EventEndTime,
                            FileName,
                            EventID,
                            DisturbanceID
                        FROM DisturbanceData
                        WHERE DisturbanceID IN
                        (
                            SELECT PhaseDisturbance.ID
                            FROM
                                dbo.GetDisturbancesInSystemEvent(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance)) InnerSequenceNumber JOIN
                                Disturbance ON Disturbance.ID = InnerSequenceNumber.ID JOIN
                                Disturbance PhaseDisturbance ON
                                    Disturbance.EventID = PhaseDisturbance.EventID AND
                                    Disturbance.StartTime = PhaseDisturbance.StartTime AND
                                    Disturbance.PerUnitMagnitude = PhaseDisturbance.PerUnitMagnitude
                            WHERE InnerSequenceNumber.SequenceNumber = OuterSequenceNumber.SequenceNumber
                        )
                        ORDER BY DisturbanceData.StartTime
                        FOR XML PATH('Disturbance'), TYPE
                    )
                FROM
                (
                    SELECT DISTINCT SequenceNumber
                    FROM dbo.GetDisturbancesInSystemEvent(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance))
                ) OuterSequenceNumber
                FOR XML PATH('DisturbanceGroup'), TYPE
            ) AS [DisturbanceGroups],
            (
                SELECT
                    FaultNumber AS [@num],
                    (
                        SELECT
                            MeterKey,
                            StationName,
                            LineName,
                            FaultType,
                            Inception,
                            DurationCycles,
                            DurationMilliseconds,
							CASE WHEN PrefaultCurrent <> -1E308 THEN FORMAT(PrefaultCurrent, '0.##########') ELSE 'NaN' END AS PrefaultCurrent,
							CASE WHEN PostfaultCurrent <> -1E308 THEN FORMAT(PostfaultCurrent, '0.##########') ELSE 'NaN' END AS PostfaultCurrent,
                            FaultCurrent,
                            Algorithm,
                            SingleEndedDistance,
                            DoubleEndedDistance,
                            DoubleEndedAngle,
                            EventStartTime,
                            EventEndTime,
                            FileName,
							ShortFileName,
                            EventID,
                            FaultSummaryID AS FaultID
                        FROM SummaryData
                        WHERE FaultSummaryID IN
                        (
                            SELECT FaultSummaryID
                            FROM
                            (
                                SELECT FaultSummaryID, ROW_NUMBER() OVER(PARTITION BY PartitionID ORDER BY OrderID) AS FaultNumber
                                FROM SummaryIDs
                                WHERE SummaryIDs.LineID = Event.LineID AND SummaryIDs.EventID IN (SELECT * FROM dbo.GetSystemEventIDs(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance)))
                            ) InnerFaultNumber
                            WHERE InnerFaultNumber.FaultNumber = OuterFaultNumber.FaultNumber
                        )
                        FOR XML PATH('SummaryData'), TYPE
                    )
                FROM
                (
                    SELECT DISTINCT ROW_NUMBER() OVER(PARTITION BY PartitionID ORDER BY OrderID) AS FaultNumber
                    FROM SummaryIDs
                    WHERE SummaryIDs.LineID = Event.LineID AND SummaryIDs.EventID IN (SELECT * FROM dbo.GetSystemEventIDs(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance)))
                ) OuterFaultNumber
                FOR XML PATH('Fault'), TYPE
            ) AS [Faults],
			(
				SELECT
					OperationNumber AS [@num],
					(
                        SELECT
                            MeterKey,
                            StationName,
                            LineName,
							BreakerNumber,
							Phase,
                            TripCoilEnergized,
                            BreakerTiming,
                            StatusTiming,
							DcOffsetDetected,
							BreakerSpeed,
							StatusBitChatter,
                            EventStartTime,
                            EventEndTime,
                            FileName,
							ShortFileName,
                            EventID,
                            BreakerOperationID
                        FROM BreakerOperationData
                        WHERE BreakerOperationID IN
                        (
                            SELECT BreakerOperationID
                            FROM
                            (
								SELECT BreakerOperationID, ROW_NUMBER() OVER(PARTITION BY PartitionID ORDER BY OrderID) AS OperationNumber
								FROM OperationIDs
								WHERE OperationIDs.LineID = Event.LineID AND OperationIDs.EventID IN (SELECT * FROM dbo.GetSystemEventIDs(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance)))
                            ) InnerOperationNumber
                            WHERE InnerOperationNumber.OperationNumber = OuterOperationNumber.OperationNumber
                        )
                        FOR XML PATH('BreakerOperationData'), TYPE
					)
				FROM
				(
					SELECT DISTINCT ROW_NUMBER() OVER(PARTITION BY PartitionID ORDER BY OrderID) AS OperationNumber
					FROM OperationIDs
					WHERE OperationIDs.LineID = Event.LineID AND OperationIDs.EventID IN (SELECT * FROM dbo.GetSystemEventIDs(Event.StartTime, Event.EndTime, (SELECT * FROM TimeTolerance)))
				) OuterOperationNumber
				FOR XML PATH('BreakerOperation'), TYPE
			) AS [BreakerOperations],
            Meter.AssetKey AS [Meter/AssetKey],
            Meter.Name AS [Meter/Name],
            Meter.ShortName AS [Meter/ShortName],
            Meter.Alias AS [Meter/Alias],
            Meter.Make AS [Meter/Make],
            Meter.Model AS [Meter/Model],
            MeterLocation.AssetKey AS [MeterLocation/AssetKey],
            MeterLocation.Name AS [MeterLocation/Name],
            MeterLocation.ShortName AS [MeterLocation/ShortName],
            MeterLocation.Alias AS [MeterLocation/Alias],
            SourceImpedance.RSrc AS [MeterLocation/RSrc],
            SourceImpedance.XSrc AS [MeterLocation/XSrc],
            Line.AssetKey AS [Line/AssetKey],
            MeterLine.LineName AS [Line/Name],
            FORMAT(Line.Length, '0.##########') AS [Line/Length],
            FORMAT(SQRT(LineImpedance.R1 * LineImpedance.R1 + LineImpedance.X1 * LineImpedance.X1), '0.##########') AS [Line/Z1],
            CASE LineImpedance.R1 WHEN 0 THEN '0' ELSE FORMAT(ATN2(LineImpedance.X1, LineImpedance.R1) * 180 / PI(), '0.##########') END AS [Line/A1],
            FORMAT(LineImpedance.R1, '0.##########') AS [Line/R1],
            FORMAT(LineImpedance.X1, '0.##########') AS [Line/X1],
            FORMAT(SQRT(LineImpedance.R0 * LineImpedance.R0 + LineImpedance.X0 * LineImpedance.X0), '0.##########') AS [Line/Z0],
            CASE LineImpedance.R0 WHEN 0 THEN '0' ELSE FORMAT(ATN2(LineImpedance.X0, LineImpedance.R0) * 180 / PI(), '0.##########') END AS [Line/A0],
            FORMAT(LineImpedance.R0, '0.##########') AS [Line/R0],
            FORMAT(LineImpedance.X0, '0.##########') AS [Line/X0],
            FORMAT(SQRT(POWER((2.0 * LineImpedance.R1 + LineImpedance.R0) / 3.0, 2) + POWER((2.0 * LineImpedance.X1 + LineImpedance.X0) / 3.0, 2)), '0.##########') AS [Line/ZS],
            CASE 2.0 * LineImpedance.R1 + LineImpedance.R0 WHEN 0 THEN '0' ELSE FORMAT(ATN2((2.0 * LineImpedance.X1 + LineImpedance.X0) / 3.0, (2.0 * LineImpedance.R1 + LineImpedance.R0) / 3.0) * 180 / PI(), '0.##########') END AS [Line/AS],
            FORMAT((2.0 * LineImpedance.R1 + LineImpedance.R0) / 3.0, '0.##########') AS [Line/RS],
            FORMAT((2.0 * LineImpedance.X1 + LineImpedance.X0) / 3.0, '0.##########') AS [Line/XS],
            (
                CAST((SELECT '<TimeTolerance>' + CAST((SELECT * FROM TimeTolerance) AS VARCHAR) + '</TimeTolerance>') AS XML)
            ) AS [Settings]
        FROM
            Meter CROSS JOIN
            Line LEFT OUTER JOIN
            MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
            MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Line.ID LEFT OUTER JOIN
            MeterLocationLine ON MeterLocationLine.MeterLocationID = MeterLocation.ID AND MeterLocationLine.LineID = Line.ID LEFT OUTER JOIN
            SourceImpedance ON SourceImpedance.MeterLocationLineID = MeterLocationLine.ID LEFT OUTER JOIN
            LineImpedance ON LineImpedance.LineID = Line.ID LEFT OUTER JOIN
            EventType ON Event.EventTypeID = EventType.ID
        WHERE
            Event.MeterID = Meter.ID AND
            Event.LineID = Line.ID
        FOR XML PATH('EventDetail'), TYPE
    ) AS EventDetail
FROM Event




GO


ALTER TABLE EventType
ADD UNIQUE NONCLUSTERED(Name)
GO

ALTER TABLE FaultGroup WITH CHECK ADD FOREIGN KEY(EventID)
REFERENCES Event(ID)
GO

ALTER TABLE FaultSegment WITH CHECK ADD FOREIGN KEY(EventID)
REFERENCES Event(ID)
GO

ALTER TABLE FaultSegment WITH CHECK ADD FOREIGN KEY(SegmentTypeID)
REFERENCES SegmentType(ID)
GO

ALTER TABLE FaultSummary
ADD ReactanceRatio FLOAT NOT NULL DEFAULT 0
GO

ALTER TABLE FaultSummary WITH CHECK ADD FOREIGN KEY(EventID)
REFERENCES Event(ID)
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER PROCEDURE [GetImpactedComponents]
    @facilityID INT,
    @magnitude FLOAT,
    @duration FLOAT
AS BEGIN
    WITH EPRITolerancePoint AS
    (
        SELECT
            ROW_NUMBER() OVER(PARTITION BY TestCurve.TestCurveID ORDER BY Y, X) AS RowNumber,
            ComponentID,
            TestCurve.TestCurveID,
            Y AS Magnitude,
            X AS Duration
        FROM
            IndustrialPQ.dbo.TestCurvePoint JOIN
            IndustrialPQ.dbo.TestCurve ON TestCurvePoint.TestCurveID = TestCurve.TestCurveID
    ),
    EPRIToleranceSegment AS
    (
        SELECT
            P1.RowNumber,
            P1.ComponentID,
            P1.TestCurveID,
            CASE WHEN @duration < P1.Duration THEN 0
                 WHEN @magnitude < P1.Magnitude THEN 1
                 WHEN @duration > P2.Duration THEN 0
                 WHEN P1.Duration = P2.Duration THEN 0
                 WHEN @duration <= (((P2.Magnitude - P1.Magnitude) / (P2.Duration - P1.Duration)) * (@duration - P1.Duration) + P1.Magnitude) THEN 1
                 ELSE 0
            END AS IsUnder,
            CASE WHEN P1.Duration > P2.Duration THEN 1
                 ELSE 0
            END AS IsBackwards
        FROM
            EPRITolerancePoint P1 LEFT OUTER JOIN
            EPRITolerancePoint P2 ON P1.TestCurveID = P2.TestCurveID AND P1.RowNumber = P2.RowNumber - 1
        WHERE
            P1.Duration <> P2.Duration
    ),
    EPRIToleranceCurve AS
    (
        SELECT
            ComponentID,
            TestCurveID,
            IsUnder
        FROM
        (
            SELECT
                ROW_NUMBER() OVER(PARTITION BY TestCurveID ORDER BY RowNumber) AS RowNumber,
                ComponentID,
                TestCurveID,
                1 - IsBackwards AS IsUnder
            FROM
                EPRIToleranceSegment
            WHERE
                IsUnder <> 0
        ) AS Temp
        WHERE
            RowNumber = 1
    ),
    USERTolerancePoint AS
    (
        SELECT
            ROW_NUMBER() OVER(PARTITION BY TestCurve.TestCurveID ORDER BY Y, X) AS RowNumber,
            ComponentID,
            TestCurve.TestCurveID,
            Y AS Magnitude,
            X AS Duration
        FROM
            UserIndustrialPQ.dbo.TestCurvePoint JOIN
            UserIndustrialPQ.dbo.TestCurve ON TestCurvePoint.TestCurveID = TestCurve.TestCurveID
    ),
    USERToleranceSegment AS
    (
        SELECT
            P1.RowNumber,
            P1.ComponentID,
            P1.TestCurveID,
            CASE WHEN @duration < P1.Duration THEN 0
                 WHEN @magnitude < P1.Magnitude THEN 1
                 WHEN @duration > P2.Duration THEN 0
                 WHEN P1.Duration = P2.Duration THEN 0
                 WHEN @duration <= (((P2.Magnitude - P1.Magnitude) / (P2.Duration - P1.Duration)) * (@duration - P1.Duration) + P1.Magnitude) THEN 1
                 ELSE 0
            END AS IsUnder,
            CASE WHEN P1.Duration > P2.Duration THEN 1
                 ELSE 0
            END AS IsBackwards
        FROM
            USERTolerancePoint P1 LEFT OUTER JOIN
            USERTolerancePoint P2 ON P1.TestCurveID = P2.TestCurveID AND P1.RowNumber = P2.RowNumber - 1
        WHERE
            P1.Duration <> P2.Duration
    ),
    USERToleranceCurve AS
    (
        SELECT
            ComponentID,
            TestCurveID,
            IsUnder
        FROM
        (
            SELECT
                ROW_NUMBER() OVER(PARTITION BY TestCurveID ORDER BY RowNumber) AS RowNumber,
                ComponentID,
                TestCurveID,
                1 - IsBackwards AS IsUnder
            FROM
                USERToleranceSegment
            WHERE
                IsUnder <> 0
        ) AS Temp
        WHERE
            RowNumber = 1
    ),
    FacilityCurve AS
    (
        SELECT
            CurveID,
            CurveDB,
            Facility.FacilityName AS Facility,
            Area.Title AS Area,
            Equipment.Title AS SectionTitle,
            Equipment.Rank AS SectionRank
        FROM
            UserIndustrialPQ.dbo.FacilityAudit JOIN
            UserIndustrialPQ.dbo.Facility ON FacilityAudit.FacilityID = Facility.FacilityID JOIN
            UserIndustrialPQ.dbo.AuditSection Equipment ON Equipment.FacilityAuditID = FacilityAudit.FacilityAuditID JOIN
            UserIndustrialPQ.dbo.AuditSectionTree ON AuditSectionTree.AuditSectionChildID = Equipment.AuditSectionID JOIN
            UserIndustrialPQ.dbo.AuditSection Area ON AuditSectionTree.AuditSectionParentID = Area.AuditSectionID JOIN
            UserIndustrialPQ.dbo.AuditCurve ON AuditCurve.AuditSectionID = Equipment.AuditSectionID
        WHERE
            AuditCurve.CurveType = 'TOLERANCE' AND
            FacilityAudit.FacilityID = @facilityID
    )
    SELECT
        FacilityCurve.Facility,
        FacilityCurve.Area,
        FacilityCurve.SectionTitle,
        FacilityCurve.SectionRank,
        Component.ComponentModel,
        Manufacturer.ManufacturerName,
        Series.SeriesName,
        ComponentType.ComponentTypeName
    FROM
        IndustrialPQ.dbo.Component JOIN
        IndustrialPQ.dbo.Series ON Component.SeriesID = Series.SeriesID JOIN
        IndustrialPQ.dbo.Manufacturer ON Series.ManufacturerID = Manufacturer.ManufacturerID JOIN
        IndustrialPQ.dbo.ComponentType ON Component.ComponentTypeID = ComponentType.ComponentTypeID JOIN
        EPRIToleranceCurve ON EPRIToleranceCurve.ComponentID = Component.ComponentID JOIN
        FacilityCurve ON FacilityCurve.CurveID = EPRIToleranceCurve.TestCurveID
    WHERE
        CurveDB = 'EPRI' AND
        IsUnder <> 0
    UNION
    SELECT
        FacilityCurve.Facility,
        FacilityCurve.Area,
        FacilityCurve.SectionTitle,
        FacilityCurve.SectionRank,
        Component.ComponentModel,
        Manufacturer.ManufacturerName,
        Series.SeriesName,
        ComponentType.ComponentTypeName
    FROM
        UserIndustrialPQ.dbo.Component JOIN
        UserIndustrialPQ.dbo.Series ON Component.SeriesID = Series.SeriesID JOIN
        UserIndustrialPQ.dbo.Manufacturer ON Series.ManufacturerID = Manufacturer.ManufacturerID JOIN
        UserIndustrialPQ.dbo.ComponentType ON Component.ComponentTypeID = ComponentType.ComponentTypeID JOIN
        USERToleranceCurve ON USERToleranceCurve.ComponentID = Component.ComponentID JOIN
        FacilityCurve ON FacilityCurve.CurveID = USERToleranceCurve.TestCurveID
    WHERE
        CurveDB = 'USER' AND
        IsUnder <> 0
END



GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER PROCEDURE [GetPQIFacility]
    @facilityID INT
AS BEGIN
    SELECT
        Facility.FacilityName,
        Facility.FacilityVoltage,
        Facility.UtilitySupplyVoltage,
        Address.Address1,
        Address.Address2,
        Address.City,
        Address.StateOrProvince,
        Address.PostalCode,
        Address.Country,
        Company.CompanyName,
        Company.Industry
    FROM
        UserIndustrialPQ.dbo.Facility JOIN
        UserIndustrialPQ.dbo.Address ON Facility.AddressID = Address.AddressID JOIN
        UserIndustrialPQ.dbo.Company ON Address.CompanyID = Company.CompanyID
    WHERE
        Facility.FacilityID = @facilityID
END


GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO




ALTER FUNCTION [GetSystemEventIDs]
(
    @startTime DATETIME2,
    @endTime DATETIME2,
    @timeTolerance FLOAT
)
RETURNS @systemEvent TABLE
(
    EventID INT
)
AS BEGIN
    DECLARE @adjustedStartTime DATETIME2 = dbo.AdjustDateTime2(@startTime, -@timeTolerance)
    DECLARE @adjustedEndTime DATETIME2 = dbo.AdjustDateTime2(@endTime, @timeTolerance)
    DECLARE @minStartTime DATETIME2
    DECLARE @maxEndTime DATETIME2

    SELECT
        @minStartTime = MIN(dbo.AdjustDateTime2(StartTime, -@timeTolerance)),
        @maxEndTime = MAX(dbo.AdjustDateTime2(EndTime, @timeTolerance))
    FROM
        Event JOIN
        FileGroup ON Event.FileGroupID = FileGroup.ID
    WHERE
        StartTime <= @adjustedEndTime AND
        @adjustedStartTime <= EndTime AND
        ProcessingEndTime > '0001-01-01'

    WHILE @startTime != @minStartTime OR @endTime != @maxEndTime
    BEGIN
        SET @startTime = @minStartTime
        SET @endTime = @maxEndTime
        SET @adjustedStartTime = dbo.AdjustDateTime2(@startTime, -@timeTolerance)
        SET @adjustedEndTime = dbo.AdjustDateTime2(@endTime, @timeTolerance)

        SELECT
            @minStartTime = MIN(dbo.AdjustDateTime2(StartTime, -@timeTolerance)),
            @maxEndTime = MAX(dbo.AdjustDateTime2(EndTime, @timeTolerance))
        FROM
            Event JOIN
            FileGroup ON Event.FileGroupID = FileGroup.ID
        WHERE
            StartTime <= @adjustedEndTime AND
            @adjustedStartTime <= EndTime AND
            ProcessingEndTime > '0001-01-01'
    END

    INSERT INTO @systemEvent
    SELECT ID
    FROM Event
    WHERE @adjustedStartTime <= StartTime AND EndTime <= @adjustedEndTime

    RETURN
END

GO


ALTER TABLE LineImpedance
ADD UNIQUE NONCLUSTERED(LineID)
GO

ALTER TABLE SegmentType
ADD UNIQUE NONCLUSTERED(Name)
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 3, 2015>
-- Description: <Description, Selects All Events in the database>
-- selectBreakersForCalendar
-- =============================================
ALTER PROCEDURE [selectBreakersForCalendar]
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @counter INT = 0
DECLARE @eventDate DATE = (Select max(CAST(StartTime AS Date)) from Event) --'2015-03-23'
DECLARE @numberOfDays INT = DATEDIFF ( day , (Select min(CAST(StartTime AS Date)) from Event), @eventDate) --365*5

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp(Date DATE)

WHILE (@counter <= @numberOfDays)
BEGIN
    INSERT INTO #temp VALUES(@eventDate)
    SET @eventDate = DATEADD(DAY, 1, @eventDate)
    SET @counter = @counter + 1
END

SELECT Date as thedate, Normal as normal, late as late, indeterminate as indeterminate
FROM
(
    SELECT #temp.Date, [BreakerOperationType].Name AS EventTypeName, COALESCE(EventCount, 0) AS EventCount
    FROM
        #temp CROSS JOIN
        [BreakerOperationType] LEFT OUTER JOIN
        (
            SELECT CAST([TripCoilEnergized] AS Date) AS EventDate, [BreakerOperationTypeID] as EventTypeID, COUNT(*) AS EventCount
            FROM [BreakerOperation] join [Event] on [BreakerOperation].[EventID] = [Event].[ID] and [Event].[MeterID] in (select * from authMeters(@username))
            GROUP BY CAST([TripCoilEnergized] AS Date), [BreakerOperationTypeID]
        ) AS Event ON #temp.Date = Event.EventDate AND [BreakerOperationType].ID = Event.EventTypeID
) AS EventDate
PIVOT
(
    SUM(EventCount)
    FOR EventDate.EventTypeName IN ( normal , late , indeterminate )
) as pvt
ORDER BY Date

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 3, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectBreakersForMeterIDByDateRange '09/30/2014', '10/20/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- selectBreakersForMeterIDByDateRange '09/30/2014', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- selectBreakersForMeterIDByDateRange '09/30/2014 06:00 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- selectBreakersForMeterIDByDateRange '09/30/2014 06:43 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- =============================================
ALTER PROCEDURE [selectBreakersForMeterIDByDateRange]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

DECLARE @dateStatement NVARCHAR(200) = N'CAST(TripCoilEnergized AS Date)'
DECLARE @groupByStatement NVARCHAR(200) = N'CAST(TripCoilEnergized AS Date)'

IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
    SET @dateStatement = N'DateAdd(HOUR,DatePart(HOUR,TripCoilEnergized), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(HOUR, TripCoilEnergized), DateAdd(HOUR,DatePart(HOUR,TripCoilEnergized), @EventDateFrom)'
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
    SET @dateStatement = N'DateAdd(MINUTE,DatePart(MINUTE,TripCoilEnergized), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(MINUTE, TripCoilEnergized), DateAdd(MINUTE,DatePart(MINUTE,TripCoilEnergized), @EventDateFrom)'
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
    SET @dateStatement = N'DateAdd(SECOND,DatePart(SECOND,TripCoilEnergized), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(SECOND, TripCoilEnergized), DateAdd(SECOND,DatePart(SECOND,TripCoilEnergized), @EventDateFrom)'
END

DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

create table #TEMP (Name varchar(max))
insert into #TEMP SELECT Name FROM (Select Distinct Name FROM BreakerOperationType) as t

SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(Name as varchar(max)), '') + '],'
FROM #TEMP ORDER BY Name desc

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(Name as varchar(max)), '') + '], 0) AS [' + COALESCE(CAST(Name as varchar(max)), '') + '],'
FROM #TEMP ORDER BY Name desc

DROP TABLE #TEMP

SET @SQLStatement =
' SELECT Date as thedate, ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) +
' FROM (                                                                                                     ' +
'   SELECT ' + @dateStatement + '  AS Date,                                                          ' +
'          BreakerOperationType.Name,                                                                        ' +
'          COUNT(*) AS thecount                                                                              ' +
'   FROM BreakerOperation JOIN                                                                               ' +
'        BreakerOperationType ON BreakerOperation.BreakerOperationTypeID = BreakerOperationType.ID JOIN      ' +
'        Event ON Event.ID = BreakerOperation.EventID                                                        ' +
'   WHERE MeterID in (select * from authMeters(@username)) AND                                               ' +
'         MeterID IN (SELECT * FROM String_To_Int_Table(@MeterID, '','')) AND                                ' +
'         TripCoilEnergized >= @startDate AND TripCoilEnergized < @endDate                                   ' +
'   GROUP BY ' + @groupByStatement + ', BreakerOperationType.Name                                        ' +
') as table1                                                                                                 ' +
' PIVOT(                                                                                                     ' +
'       SUM(table1.thecount)                                                                                 ' +
'       FOR table1.Name IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')                           ' +
' ) as pvt                                                                                                   ' +
' ORDER BY Date                                                                                   '

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DateTime ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom


END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 3, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectBreakersForMeterIDsByDate '01/10/2013', '05/10/2015', '0'
-- selectBreakersForMeterIDsByDate '03/30/2015', '03/30/2015', '13,17,46,40,6,52,15,16,28,57,19,55,53,12,58,54,8,59,18,20,9,11,21,1,41,39,23,51,14,45,47,2,50,56,30,42,32,10,22,29,48,24,43,34,4,37,26,36,25,31,44,49,3,7,27,35,33,38,5,'
-- =============================================
ALTER PROCEDURE [selectBreakersForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp (thesiteid int, thesitename varchar(100))

INSERT INTO #temp Select [dbo].[Meter].[ID], [dbo].[Meter].[Name] from [dbo].[Meter] where [dbo].[Meter].[ID] in (select * from authMeters(@username))

SELECT thesiteid as siteid, thesitename as sitename , Normal as normal, Late as late, Indeterminate as indeterminate
FROM
(
    SELECT #temp.thesiteid, #temp.thesitename , [BreakerOperationType].Name AS EventTypeName, COALESCE(EventCount, 0) AS EventCount

    FROM
        #temp CROSS JOIN
        [BreakerOperationType] LEFT OUTER JOIN
        (
            SELECT MeterID, [BreakerOperationTypeID], COUNT(*) AS EventCount
            FROM [BreakerOperation] join [Event] on [BreakerOperation].[EventID] = [Event].[ID]
            where MeterID in (Select * from @MeterIDs)
            and (CAST([TripCoilEnergized] as Date) between @EventDateFrom and @EventDateTo)
            GROUP BY [BreakerOperationTypeID], MeterID
        ) AS E ON [BreakerOperationType].ID = E.[BreakerOperationTypeID] and E.MeterID = #temp.thesiteid
) AS EventDate
PIVOT
(
    SUM(EventCount)
    FOR EventDate.EventTypeName IN (normal, late, indeterminate)
) as pvt
ORDER BY sitename asc

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Aug 31, 2015>
-- Description: <Description, Selects Correctness for a MeterID by Date for date range>
-- selectCompletenessForMeterIDByDateRange '01/10/2013', '05/10/2015', '0'
-- selectCompletenessForMeterIDByDateRange '01/01/2014', '01/01/2015', '108,109,86,87,110,118,13,17,167,168,77,78,79,80,70,46,169,185,186,40,6,170,88,89,52,192,15,16,91,92,93,94,95,96,97,28,98,99,100,101,102,171,57,172,125,173,63,19,104,174,55,105,106,107,103,111,112,113,60,53,160,114,115,116,117,68,12,58,54,8,59,18,20,9,193,119,120,81,164,121,175,156,157,176,177,11,122,123,21,65,1,41,39,23,51,127,128,129,130,165,76,131,132,133,134,135,136,137,14,124,45,47,73,64,2,138,139,140,141,142,143,82,83,62,50,144,145,56,30,42,146,147,148,149,150,151,32,152,126,74,67,10,66,22,178,179,29,180,48,181,153,154,155,194,24,43,34,4,69,37,158,26,182,36,159,161,162,163,71,166,25,31,44,49,72,61,75,187,188,189,190,191,3,84,85,7,195,90,183,27,196,184,35,33,197,198,199,200,201,38,5,', 'jwalker'
-- =============================================
ALTER PROCEDURE [selectCompletenessForMeterIDByDateRange]
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
DECLARE @endDate DATE = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

SELECT  Date as thedate, COALESCE(First, 0) AS '> 100%', COALESCE(Second, 0) AS '98% - 100%', COALESCE(Third, 0) AS '90% - 97%', COALESCE(Fourth, 0) AS '70% - 89%', COALESCE(Fifth, 0) AS '50% - 69%', COALESCE(Sixth, 0) AS '>0% - 49%'
FROM
    (
        SELECT Date, CompletenessLevel, COUNT(*) AS MeterCount
        FROM
        (
            SELECT Date,
                    CASE
                        WHEN Completeness >= 100.0 THEN 'First'
                        WHEN 98.0 <= Completeness AND Completeness < 100.0 THEN 'Second'
                        WHEN 90.0 <= Completeness AND Completeness < 98.0 THEN 'Third'
                        WHEN 70.0 <= Completeness AND Completeness < 90.0 THEN 'Fourth'
                        WHEN 50.0 <= Completeness AND Completeness < 70.0 THEN 'Fifth'
                        WHEN 0.0 < Completeness AND Completeness < 50.0 THEN 'Sixth'
                    END AS CompletenessLevel
            FROM
            (
                SELECT Date, 100.0 * CAST(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints AS FLOAT) / CAST(NULLIF(ExpectedPoints, 0) AS FLOAT) AS Completeness
                FROM MeterDataQualitySummary
                WHERE Date BETWEEN @startDate AND @endDate AND MeterID IN (SELECT * FROM String_To_Int_Table(@MeterID, ',')) AND MeterID IN (SELECT * FROM authMeters(@username))
            ) MeterDataQualitySummary
        ) MeterDataQualitySummary
        GROUP BY Date, CompletenessLevel
) MeterDataQualitySummary
PIVOT
(
    SUM(MeterDataQualitySummary.MeterCount)
    FOR MeterDataQualitySummary.CompletenessLevel IN (First, Second, Third, Fourth, Fifth, Sixth)
) as pvt
ORDER BY Date

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, August 31, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectCompletenessForMeterIDsByDate '01/10/2013', '05/10/2015', '0', 'jwalker'
-- selectCompletenessForMeterIDsByDate '08/01/2006', '08/31/2015', '32,33,10,11,34,42,91,92,1,2,3,4,93,109,110,94,12,13,116,15,16,17,18,19,20,21,22,23,24,25,26,95,96,49,97,28,98,29,30,31,27,35,36,37,84,38,39,40,41,117,43,44,5,88,45,99,80,81,100,101,46,47,51,52,53,54,89,55,56,57,58,59,60,61,48,62,63,64,65,66,67,6,7,68,69,70,71,72,73,74,75,76,50,102,103,104,105,77,78,79,118,82,106,83,85,86,87,90,111,112,113,114,115,8,9,119,14,107,120,108,121,122,123,124,125,', 'jwalker'
-- selectCompletenessForMeterIDsByDate '08/01/2015', '08/31/2015', '32,33,10,11,34,42,91,92,1,2,3,4,93,109,110,94,12,13,116,15,16,17,18,19,20,21,22,23,24,25,26,95,96,49,97,28,98,29,30,31,27,35,36,37,84,38,39,40,41,117,43,44,5,88,45,99,80,81,100,101,46,47,51,52,53,54,89,55,56,57,58,59,60,61,48,62,63,64,65,66,67,6,7,68,69,70,71,72,73,74,75,76,50,102,103,104,105,77,78,79,118,82,106,83,85,86,87,90,111,112,113,114,115,8,9,119,14,107,120,108,121,122,123,124,125,', 'jwalker'
-- =============================================
ALTER PROCEDURE [selectCompletenessForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #meters (
thesiteid int,
thesitename varchar(100)
)

INSERT INTO #meters Select
[dbo].[Meter].[ID] as thesiteid,
[dbo].[Meter].[Name] as thesitename
from [dbo].[Meter] where Meter.ID in (Select * from @MeterIDs)

DECLARE @thesiteid int
DECLARE @thesitename varchar(100)

CREATE TABLE #temp (
siteId int,
siteName varchar(100),
ExpectedPoints int,
GoodPoints int,
LatchedPoints int,
UnreasonablePoints int,
NoncongruentPoints int,
DuplicatePoints int
)

DECLARE db_cursor CURSOR FOR
SELECT thesiteid, thesitename FROM #meters

OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @thesiteid , @thesitename

WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #temp
SELECT
    @thesiteid,
    @thesitename,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[ExpectedPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as ExpectedPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[GoodPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as GoodPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[LatchedPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as LatchedPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[UnreasonablePoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as UnreasonablePoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[NoncongruentPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as NoncongruentPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[DuplicatePoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as DuplicatePoints

    FETCH NEXT FROM db_cursor INTO @thesiteid , @thesitename
END

CLOSE db_cursor
DEALLOCATE db_cursor

select * from #temp

drop Table #temp
drop Table #meters

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Aug 31, 2015>
-- Description: <Description, Selects Correctness for a MeterID by Date for date range>
-- [selectCorrectnessForMeterIDByDateRange] '01/10/2013', '05/10/2015', '0'
-- [selectCorrectnessForMeterIDByDateRange] '08/05/2007', '09/04/2008', '108,109,86,87,110,118,13,17,167,168,77,78,79,80,70,46,169,185,186,40,6,170,88,89,52,192,15,16,91,92,93,94,95,96,97,28,98,99,100,101,102,171,57,172,125,173,63,19,104,174,55,105,106,107,103,111,112,113,60,53,160,114,115,116,117,68,12,58,54,8,59,18,20,9,193,119,120,81,164,121,175,156,157,176,177,11,122,123,21,65,1,41,39,23,51,127,128,129,130,165,76,131,132,133,134,135,136,137,14,124,45,47,73,64,2,138,139,140,141,142,143,82,83,62,50,144,145,56,30,42,146,147,148,149,150,151,32,152,126,74,67,10,66,22,178,179,29,180,48,181,153,154,155,194,24,43,34,4,69,37,158,26,182,36,159,161,162,163,71,166,25,31,44,49,72,61,75,187,188,189,190,191,3,84,85,7,195,90,183,27,196,184,35,33,197,198,199,200,201,38,5,', 'jwalker'
-- =============================================
ALTER PROCEDURE [selectCorrectnessForMeterIDByDateRange]
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
DECLARE @endDate DATE = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

SELECT  Date as thedate, COALESCE(First, 0) AS '> 100%', COALESCE(Second, 0) AS '98% - 100%', COALESCE(Third, 0) AS '90% - 97%', COALESCE(Fourth, 0) AS '70% - 89%', COALESCE(Fifth, 0) AS '50% - 69%', COALESCE(Sixth, 0) AS '>0% - 49%'
FROM
    (
        SELECT Date, CompletenessLevel, COUNT(*) AS MeterCount
        FROM
        (
            SELECT Date,
                    CASE
                        WHEN Correctness >= 100.0 THEN 'First'
                        WHEN 98.0 <= Correctness AND Correctness < 100.0 THEN 'Second'
                        WHEN 90.0 <= Correctness AND Correctness < 98.0 THEN 'Third'
                        WHEN 70.0 <= Correctness AND Correctness < 90.0 THEN 'Fourth'
                        WHEN 50.0 <= Correctness AND Correctness < 70.0 THEN 'Fifth'
                        WHEN 0.0 < Correctness AND Correctness < 50.0 THEN 'Sixth'
                    END AS CompletenessLevel
            FROM
            (
                SELECT Date, 100.0 * CAST(GoodPoints AS FLOAT) / CAST(NULLIF(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints, 0) AS FLOAT) AS Correctness
                FROM MeterDataQualitySummary
                WHERE Date BETWEEN @startDate AND @endDate AND MeterID IN (SELECT * FROM String_To_Int_Table(@MeterID, ',')) AND MeterID IN (SELECT * FROM authMeters(@username))
            ) MeterDataQualitySummary
        ) MeterDataQualitySummary
        GROUP BY Date, CompletenessLevel
) MeterDataQualitySummary
PIVOT
(
    SUM(MeterDataQualitySummary.MeterCount)
    FOR MeterDataQualitySummary.CompletenessLevel IN (First, Second, Third, Fourth, Fifth, Sixth)
) as pvt
ORDER BY Date

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, August 31, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectCorrectnessForMeterIDsByDate '01/10/2013', '05/10/2015', '0', 'jwalker'
-- selectCorrectnessForMeterIDsByDate '01/01/2007', '01/01/2008', '1,2,3,4,5,6,7,8,9,', 'jwalker'
-- selectCorrectnessForMeterIDsByDate '08/01/2015', '08/31/2015', '32,33,10,11,34,42,91,92,1,2,3,4,93,109,110,94,12,13,116,15,16,17,18,19,20,21,22,23,24,25,26,95,96,49,97,28,98,29,30,31,27,35,36,37,84,38,39,40,41,117,43,44,5,88,45,99,80,81,100,101,46,47,51,52,53,54,89,55,56,57,58,59,60,61,48,62,63,64,65,66,67,6,7,68,69,70,71,72,73,74,75,76,50,102,103,104,105,77,78,79,118,82,106,83,85,86,87,90,111,112,113,114,115,8,9,119,14,107,120,108,121,122,123,124,125,', 'jwalker'
-- =============================================
ALTER PROCEDURE [selectCorrectnessForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #meters (
thesiteid int,
thesitename varchar(100)
)

INSERT INTO #meters Select
[dbo].[Meter].[ID] as thesiteid,
[dbo].[Meter].[Name] as thesitename
from [dbo].[Meter] where Meter.ID in (Select * from @MeterIDs)

DECLARE @thesiteid int
DECLARE @thesitename varchar(100)

CREATE TABLE #temp (
siteId int,
siteName varchar(100),
ExpectedPoints int,
GoodPoints int,
LatchedPoints int,
UnreasonablePoints int,
NoncongruentPoints int,
DuplicatePoints int
)

DECLARE db_cursor CURSOR FOR
SELECT thesiteid, thesitename FROM #meters

OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @thesiteid , @thesitename

WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #temp
SELECT
    @thesiteid,
    @thesitename,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[ExpectedPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as ExpectedPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[GoodPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as GoodPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[LatchedPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as LatchedPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[UnreasonablePoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as UnreasonablePoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[NoncongruentPoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as NoncongruentPoints,
    (Select Coalesce(SUM([dbo].[MeterDataQualitySummary].[DuplicatePoints]), 0) from [MeterDataQualitySummary] where @thesiteid = MeterID and CAST([Date] as Date) between @EventDateFrom and @EventDateTo) as DuplicatePoints

    FETCH NEXT FROM db_cursor INTO @thesiteid , @thesitename
END

CLOSE db_cursor
DEALLOCATE db_cursor

select * from #temp

drop Table #temp
drop Table #meters

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, August 27, 2015>
-- Description: <Description, Selects All Events in the database>
-- selectDashSettings 'jwalker'
-- =============================================
ALTER PROCEDURE [selectDashSettings]
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

    Select * from [DashSettings]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, April 30, 2015>
-- Description: <Description, Selects Double Ended Fault Distance by EventID>
-- selectDoubleEndedFaultDistanceForEventID '1'

-- =============================================
ALTER PROCEDURE [selectDoubleEndedFaultDistanceForEventID]
    -- Add the parameters for the stored procedure here
    @EventID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    select Distance, Angle from DoubleEndedFaultSummary where EventID = @EventID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Nov 10, 2014>
-- Description: <Description, Selects tMeasurementCharacteristic for a MeterID by Date for day>
-- [selectEventInstance] '11/17/2008', 10, 2
-- =============================================
ALTER PROCEDURE [selectEventInstance]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @Type as int

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  SELECT [dbo].[Event].[ID] as value, [dbo].[Event].[StartTime] as text, [dbo].[MeterLine].[LineName] as linename FROM [dbo].[Event]
  join [dbo].[Line] on [dbo].[Event].[LineID] = [dbo].[Line].[ID]
  join [dbo].[MeterLine] on [dbo].[MeterLine].[LineID] = [dbo].[Line].[ID] and [dbo].[MeterLine].[MeterID] = [dbo].[Event].[MeterID]
  where (CAST([dbo].[Event].[StartTime] as Date) = @theDate) and
  [dbo].[Event].[EventTypeID] = @Type and
  [dbo].[Event].[MeterID] = @MeterID
  order by [dbo].[Event].[StartTime]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jan 12, 2015>
-- Description: <Description, Selects EventInstances for a MeterID by Date for day>
-- [selectEventInstancesByMeterDate] '11/17/2008', 10
-- =============================================
ALTER PROCEDURE [selectEventInstancesByMeterDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  SELECT [dbo].[Event].[ID] as value, [dbo].[Event].[StartTime] as text FROM [dbo].[Event]
  where (CAST([dbo].[Event].[StartTime] as Date) = @theDate) and
  [dbo].[Event].[MeterID] = @MeterID
  order by [dbo].[Event].[StartTime]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jan 12, 2015>
-- Description: <Description, Selects EventInstances for a MeterID and LineID by Date for day>
-- [selectEventInstancesByMeterLineDate] '06/17/2013', 7 , 30
-- =============================================
ALTER PROCEDURE [selectEventInstancesByMeterLineDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @LineID as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  SELECT [dbo].[Event].[ID] as value, [dbo].[Event].[StartTime] as text , [dbo].[EventType].[Name] as type FROM [dbo].[Event]
  join [dbo].[EventType] on [dbo].[EventType].[ID] = [dbo].[Event].[EventTypeID]
  where (CAST([dbo].[Event].[StartTime] as Date) = @theDate) and
  [dbo].[Event].[LineID] = @LineID --and
  --[dbo].[Event].[MeterID] = @MeterID
  order by [dbo].[Event].[EventTypeID] , [dbo].[Event].[StartTime]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects All Events in the database>
-- selectEventsForCalendar 'jwalker'
-- =============================================
ALTER PROCEDURE [selectEventsForCalendar]
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @counter INT = 0
DECLARE @eventDate DATE = (Select max(CAST(StartTime AS Date)) from Event) --'2015-03-23'
DECLARE @numberOfDays INT = DATEDIFF ( day , (Select min(CAST(StartTime AS Date)) from Event), @eventDate) --365*5

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp(Date DATE)

WHILE (@counter <= @numberOfDays)
BEGIN
    INSERT INTO #temp VALUES(@eventDate)
    SET @eventDate = DATEADD(DAY, 1, @eventDate)
    SET @counter = @counter + 1
END

SELECT Date as thedate, Fault as faults, Interruption as interruptions, Sag as sags, Swell as swells, Other as others
FROM
(
    SELECT #temp.Date, EventType.Name AS EventTypeName, COALESCE(EventCount, 0) AS EventCount
    FROM
        #temp CROSS JOIN
        EventType LEFT OUTER JOIN
        (
            SELECT CAST(StartTime AS Date) AS EventDate, EventTypeID, COUNT(*) AS EventCount
            FROM Event where Event.MeterID in (select * from authMeters(@username))
            GROUP BY CAST(StartTime AS Date), EventTypeID
        ) AS Event ON #temp.Date = Event.EventDate AND EventType.ID = Event.EventTypeID
) AS EventDate
PIVOT
(
    SUM(EventCount)
    FOR EventDate.EventTypeName IN (Fault, Interruption, Sag, Swell, Other)
) as pvt
ORDER BY Date

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Billy Ernest>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectEventsForMeterIDByDateRange '11/08/2016', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- selectEventsForMeterIDByDateRange '11/08/2016', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- selectEventsForMeterIDByDateRange '11/08/2016 03:00 PM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- selectEventsForMeterIDByDateRange '11/08/2016 03:37 PM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- =============================================
ALTER PROCEDURE [selectEventsForMeterIDByDateRange]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)

AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

DECLARE @dateStatement NVARCHAR(200) = N'CAST(StartTime AS Date)'
DECLARE @groupByStatement NVARCHAR(200) = N'CAST(StartTime AS Date)'

IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
    SET @dateStatement = N'DateAdd(HOUR,DatePart(HOUR,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(HOUR, StartTime), DateAdd(HOUR,DatePart(HOUR,StartTime), @EventDateFrom)'
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
    SET @dateStatement = N'DateAdd(MINUTE,DatePart(MINUTE,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(MINUTE, StartTime), DateAdd(MINUTE,DatePart(MINUTE,StartTime), @EventDateFrom)'
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
    SET @dateStatement = N'DateAdd(SECOND,DatePart(SECOND,StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(SECOND, StartTime), DateAdd(SECOND,DatePart(SECOND,StartTime), @EventDateFrom)'
END



DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

SELECT @PivotColumns = @PivotColumns + '[' + t.Name + '],'
FROM (Select Name FROM EventType) AS t

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + t.Name + '], 0) AS [' + t.Name + '],'
FROM (Select Name FROM EventType) AS t

SET @SQLStatement =
' 
DECLARE @user varchar(max) = @username
DECLARE @ids varchar(max) = @MeterID
DECLARE @start DateTime = @startDate
DECLARE @end DateTime = @endDate

SELECT Date as thedate, ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
FROM (
		SELECT ' + @dateStatement + ' as Date, COUNT(*) AS EventCount, EventType.Name as Name
		FROM Event JOIN
		EventType ON Event.EventTypeID = EventType.ID 
       WHERE 
			MeterID in (select * from authMeters(@user)) AND 
			MeterID IN (SELECT * FROM String_To_Int_Table( @ids,  '','')) AND 
			 StartTime >= @start AND StartTime < @end  
       GROUP BY ' + @groupByStatement + ', EventType.Name 
       ) as ed 
 PIVOT( 
		SUM(ed.EventCount)
		FOR ed.Name IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ') 
 ) as pvt 
 ORDER BY Date '

--print @startDate
--print @endDate
print @sqlstatement

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DATETIME ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom


END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectEventsForMeterIDsByDate '01/10/2013', '05/10/2015', '58,', 'jwalker'
-- selectEventsForMeterIDsByDate '03/12/2013', '03/12/2014', '13,17,46,40,6,52,15,16,28,57,19,55,53,12,58,54,8,59,18,20,9,11,21,1,41,39,23,51,14,45,47,2,50,56,30,42,32,10,22,29,48,24,43,34,4,37,26,36,25,31,44,49,3,7,27,35,33,38,5,' , 'External'
-- =============================================
ALTER PROCEDURE [selectEventsForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp (thesiteid int, thesitename varchar(100))

INSERT INTO #temp Select [dbo].[Meter].[ID], [dbo].[Meter].[Name] from [dbo].[Meter] where Meter.ID in (Select * from @MeterIDs)

SELECT thesiteid as siteid, thesitename as sitename , Fault as faults, Interruption as interruptions, Sag as sags, Swell as swells, Other as others, Transient as transients
FROM
(
    SELECT #temp.thesiteid, #temp.thesitename , EventType.Name AS EventTypeName, COALESCE(EventCount, 0) AS EventCount
    FROM
        #temp CROSS JOIN
        EventType LEFT OUTER JOIN
        (
            SELECT MeterID, EventTypeID, COUNT(*) AS EventCount
            FROM Event
            WHERE (CAST([StartTime] as Date) between @EventDateFrom and @EventDateTo)
            GROUP BY EventTypeID, MeterID
        ) AS E ON EventType.ID = E.EventTypeID and E.MeterID = #temp.thesiteid
) AS EventDate
PIVOT
(
    SUM(EventCount)
    FOR EventDate.EventTypeName IN (Fault, Interruption, Sag, Swell, Other, Transient)
) as pvt
ORDER BY sitename asc

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Nov 10, 2014>
-- Description: <Description, Selects MeasurementTypes for a MeterID by Date for a day>
-- [selectEventType] '11/09/2008', 10

-- =============================================
ALTER PROCEDURE [selectEventType]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  -- EventType
  SELECT distinct [dbo].[EventType].[ID] as value, [dbo].[EventType].[Name] as text, [dbo].[Event].[StartTime] from [dbo].[EventType]

  join [dbo].[Event] on
  [dbo].[Event].[EventTypeID] = [dbo].[EventType].[ID] and
  CAST([dbo].[Event].[StartTime] as Date) = @theDate and
  [dbo].[Event].[MeterID] = @MeterID

  order by [dbo].[Event].[StartTime]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 11, 2014>
-- Description: <Description, Fault Counts and Location of all meters for a day>
-- =============================================

--[selectFaultHeatmapForDate] '06/01/2008'

ALTER PROCEDURE [selectFaultHeatmapForDate]
    @EventDate DateTime
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @thedate DATE = CAST(@EventDate AS DATE)

    SELECT
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        (
            SELECT COUNT(Event.ID)
            FROM
                Event JOIN
                EventType ON EventType.ID = Event.EventTypeID AND EventType.Name = 'Fault'
            WHERE
                Meter.ID = Event.MeterID AND
                CAST([StartTime] AS DATE) = @thedate
        ) AS Event_Count
    FROM
        Meter JOIN
        Meterlocation ON Meter.MeterLocationID = MeterLocation.ID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, June 11, 2015>
-- Description: <Description, Returns count of faults of type>
-- =============================================

--[selectFaultHistoryByLineIDType] 262,'AB'

ALTER PROCEDURE [selectFaultHistoryByLineIDType]
    @LineID as int,
    @FaultType as varchar(20)
AS
BEGIN

declare @test as float
declare @test2 as float

Select
  (SELECT count ([FaultSummary].[ID])  FROM [FaultSummary] join [Event] on [Event].[ID] = [FaultSummary].[EventID]
  where [IsSelectedAlgorithm] = 1 and [IsValid] = 1 and [IsSuppressed] = 0 and [LineID] = @LineID) total,

  (SELECT count ([FaultSummary].[ID]) FROM [FaultSummary] join [Event] on [Event].[ID] = [FaultSummary].[EventID]
  where [IsSelectedAlgorithm] = 1 and [IsValid] = 1 and [IsSuppressed] = 0 and [LineID] = @LineID and [FaultType] = @FaultType) as faultcount

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Mar 2, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for @NumberOfDays days back>
-- selectFaultsForMeterIDByDateRange '08/05/2014', '08/20/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- selectFaultsForMeterIDByDateRange '08/08/2014', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- selectFaultsForMeterIDByDateRange '08/08/2014 09:00 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- selectFaultsForMeterIDByDateRange '08/08/2014 09:34 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- =============================================
ALTER PROCEDURE [selectFaultsForMeterIDByDateRange]
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

DECLARE @dateStatement NVARCHAR(200) = N'CAST(Event.StartTime AS Date)'
DECLARE @groupByStatement NVARCHAR(200) = N'CAST(Event.StartTime AS Date)'

IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
    SET @dateStatement = N'DateAdd(HOUR,DatePart(HOUR,Event.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(HOUR, Event.StartTime), DateAdd(HOUR,DatePart(HOUR,Event.StartTime), @EventDateFrom)'
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
    SET @dateStatement = N'DateAdd(MINUTE,DatePart(MINUTE,Event.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(MINUTE, Event.StartTime), DateAdd(MINUTE,DatePart(MINUTE,Event.StartTime), @EventDateFrom)'
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
    SET @dateStatement = N'DateAdd(SECOND,DatePart(SECOND,Event.StartTime), @EventDateFrom)'
    SET @groupByStatement = N'DATEPART(SECOND, Event.StartTime), DateAdd(SECOND,DatePart(SECOND,Event.StartTime), @EventDateFrom)'
END



DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '],'
FROM (Select Distinct Line.VoltageKV
        FROM Line) AS t

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '], 0) AS [' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '],'
FROM (Select Distinct Line.VoltageKV
        FROM Line) AS t

SET @SQLStatement =
' SELECT Date as thedate, ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) +
' FROM ( ' +
'       SELECT ' + @dateStatement + ' AS Date, Line.VoltageKV, COUNT(*) AS thecount ' +
'       FROM Event JOIN '+
'       EventType ON Event.EventTypeID = EventType.ID JOIN ' +
'       Line ON Event.LineID = Line.ID ' +
'       WHERE EventType.Name = ''Fault'' AND ' +
'       MeterID in (select * from authMeters(@username)) AND MeterID IN (SELECT * FROM String_To_Int_Table( @MeterID,  '','')) AND Event.StartTime >= @startDate AND Event.StartTime < @endDate  ' +
'       GROUP BY ' + @groupByStatement + ', EventType.Name, Line.VoltageKV ' +
'       ) as eventtable ' +
' PIVOT( ' +
'       SUM(eventtable.thecount) ' +
'       FOR eventtable.VoltageKV IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ') ' +
' ) as pvt ' +
' ORDER BY Date '

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DateTime ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectFaultsForMeterIDsByDate '03/12/2013', '03/12/2014', '13,17,46,40,6,52,15,16,28,57,19,55,53,12,58,54,8,59,18,20,9,11,21,1,41,39,23,51,14,45,47,2,50,56,30,42,32,10,22,29,48,24,43,34,4,37,26,36,25,31,44,49,3,7,27,35,33,38,5,' , 'jwalker'
-- =============================================
ALTER PROCEDURE [selectFaultsForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);

INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp (thesiteid int, thesitename varchar(100))

INSERT INTO #temp Select [dbo].[Meter].[ID], [dbo].[Meter].[Name] from [dbo].[Meter] where [dbo].[Meter].[ID] in (Select * from @MeterIDs)

SELECT thesiteid as siteid, thesitename as sitename , Fault as faults
FROM
(
    SELECT #temp.thesiteid, #temp.thesitename , EventType.Name AS EventTypeName, COALESCE(EventCount, 0) AS EventCount
    FROM
        #temp CROSS JOIN
        EventType LEFT OUTER JOIN
        (
            SELECT MeterID, EventTypeID, COUNT(*) AS EventCount FROM Event
            where MeterID in (Select * from @MeterIDs)
            and (CAST([StartTime] as Date) between @EventDateFrom and @EventDateTo)

            GROUP BY EventTypeID, MeterID
        ) AS E ON EventType.ID = E.EventTypeID and E.MeterID = #temp.thesiteid and EventType.Name = 'Fault'
) AS EventDate
PIVOT
(
    SUM(EventCount)
    FOR EventDate.EventTypeName IN (Fault, Interruption, Sag, Swell, Other)
) as pvt
ORDER BY sitename asc

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Oct 2, 2015>
-- Description: <Description, Selects Double Ended Fault Distance by EventID>
-- [selectHasICFResult] '1'

-- =============================================
ALTER PROCEDURE [selectHasICFResult]
    -- Add the parameters for the stored procedure here
    @EventID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    return dbo.HasICFResult(@EventID)

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day>
-- selectHeatmapMeterLocationsTrending2 '09/29/2014 00:00:00.0000000', '5,6,7,8,21,22,23,24,25,38,39,40,41,55,56,57,58,72,73,74,75,88,89,90,91,105,106,107,108,122,123,124,125,138,139,140,141,142,155,156,157,158,172,173,174,175,189,190,191,192,13,14,15,16,30,31,32,33,46,47,48,49,50,63,64,65,66,80,81,82,83,97,98,99,100,113,114,115,116,130,131,132,133,147,148,149,150,163,164,165,166,167,180,181,182,183,197,198,199,200,2,4,9,11,18,20,27,29,34,36,43,45,52,54,59,61,68,70,77,79,84,86,93,95,102,104,109,111,118,120,127,129,134,136,143,145,152,154,159,161,168,170,177,179,184,186,188,193,195,1,3,10,12,17,19,26,28,35,37,42,44,51,53,60,62,67,69,71,76,78,85,87,92,94,96,101,103,110,112,117,119,121,126,128,135,137,144,146,151,153,160,162,169,171,176,178,185,187,194,196,201,','jwalker'
-- =============================================
ALTER PROCEDURE [selectHeatmapMeterLocationsTrending]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime2,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @ChannelList VARCHAR(MAX)

--SELECT @ChannelList = CAST([dbo].[Channel].[ID] as Varchar(Max)) + ',' + @ChannelList

SELECT @ChannelList = Coalesce(@ChannelList+ ',','') + CAST([dbo].[Channel].[ID] as Varchar(Max))

  FROM [dbo].[Channel] join [dbo].[Meter] on [dbo].[Meter].[ID] = [dbo].[Channel].[MeterID] and [dbo].[Meter].[ID] in (Select ID from @MeterIDs)
  where [dbo].[Channel].[MeasurementCharacteristicID] =
  (
  SELECT [ID]
  FROM [dbo].[MeasurementCharacteristic] where Name = 'TotalTHD'
  )
  and
  [dbo].[Channel].[PhaseID] =
  (
  SELECT [ID]
  FROM [dbo].[Phase] where Name = 'AN'
  )

  --Print @ChannelList

BEGIN

WITH TrendingDataPoint AS
(
    SELECT
        ChannelID,
        SeriesType,
        Time,
        Value
    FROM
        GetTrendingData(@EventDate, DATEADD(NANOSECOND, -100, DATEADD(minute, 5, @EventDate)), @ChannelList, default) AS TrendingData JOIN
        (
            SELECT 0 AS ID, 'Minimum' AS SeriesType UNION
            SELECT 1 AS ID, 'Maximum' AS SeriesType UNION
            SELECT 2 AS ID, 'Average' AS SeriesType
        ) AS Series ON TrendingData.SeriesID = Series.ID
),
TrendingData AS
(
    SELECT
        ChannelID,
        Time,
        Maximum,
        Minimum,
        Average
    FROM TrendingDataPoint
    PIVOT
    (
        SUM(Value)
        FOR SeriesType IN (Maximum, Minimum, Average)
    ) AS TrendingData
)
SELECT
Coalesce([dbo].[Meter].[ID],0) as MeterID,
[dbo].[MeterLocation].[Longitude] as Longitude,
[dbo].[MeterLocation].[Latitude] as Latitude,
[TrendingData].[Time] as thedate,
Cast(Round(([TrendingData].[Maximum] * 100),0) as Int) as Value

FROM [TrendingData]
    left outer join [dbo].[AlarmRangeLimit] on [dbo].[AlarmRangeLimit].[ChannelID] = [TrendingData].[ChannelID]
    left outer join [dbo].[HourOfWeekLimit] on [dbo].[HourOfWeekLimit].[ChannelID] = [TrendingData].[ChannelID]
    join [dbo].[Channel] on [dbo].[Channel].[ID] = TrendingData.ChannelID
    join [dbo].[Meter] on [dbo].[Meter].[ID] = [dbo].[Channel].[MeterID]
    join [dbo].[Meterlocation] on [dbo].[Meter].[MeterLocationID] = [dbo].[MeterLocation].[ID]
  where
      ([dbo].[HourOfWeekLimit].[HourOfWeek] = 0 or [dbo].[HourOfWeekLimit].[HourOfWeek] is null)
    order by [TrendingData].[Time]

END

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jan 12, 2015>
-- Description: <Description, Selects Lines for Events at a MeterID by Date for a day>
-- [selectLineNames] '11/09/2008', 10

-- =============================================
ALTER PROCEDURE [selectLineNames]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  -- EventType
  SELECT distinct [dbo].[Event].[LineID] as value, [dbo].[MeterLine].[LineName] as text, [dbo].[Event].[StartTime] from [dbo].[Event]

  join [dbo].[Line] on [dbo].[Event].[LineID] = [dbo].[Line].[ID] and CAST([dbo].[Event].[StartTime] as Date) = @theDate
  join [dbo].[MeterLine] on [dbo].[MeterLine].[LineID] = [dbo].[Event].[LineID]
  order by [dbo].[Event].[StartTime]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects tMeasurementCharacteristic for a MeterID by Date for day>
-- selectMeasurementCharacteristic '04/07/2008', 61, 1

-- =============================================
ALTER PROCEDURE [selectMeasurementCharacteristic]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @Type as int

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  SELECT distinct [dbo].[MeasurementCharacteristic].[ID] as value,  [dbo].[MeasurementCharacteristic].[Name] as text FROM [dbo].[DailyTrendingSummary]

  join [dbo].[Channel] on [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[Channel].[ID] and [DailyTrendingSummary].[Date] = @theDate
  join [dbo].[Meter] on [dbo].[Channel].[MeterID] = [dbo].[Meter].[ID] and [dbo].[Meter].[ID] = @MeterID
  join [dbo].[MeasurementCharacteristic] on [dbo].[Channel].[MeasurementCharacteristicID] = [dbo].[MeasurementCharacteristic].[ID]
  join [dbo].[MeasurementType] on [dbo].[Channel].[MeasurementTypeID] = @Type
  order by [dbo].[MeasurementCharacteristic].[ID]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects MeasurementTypes for a MeterID by Date for a day>
-- selectMeasurementTypes '09/08/2007', 98

-- =============================================
ALTER PROCEDURE [selectMeasurementTypes]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  -- MeasurementType
  SELECT distinct [dbo].[MeasurementType].[ID] as value,  [dbo].[MeasurementType].[Name] as text FROM [dbo].[MeasurementType]
  join [dbo].[Channel] on [dbo].[Channel].[MeasurementTypeID] = [dbo].[MeasurementType].[ID]
  join [dbo].[DailyTrendingSummary] on [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[Channel].[ID] and [Date] = @theDate
  join [dbo].[Meter] on [dbo].[Channel].[MeterID] = [dbo].[Meter].[ID] and [dbo].[Meter].[ID] = @MeterID
  order by [dbo].[MeasurementType].[ID]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, June 16, 2014>
-- Description: <Description, Selects meters within rectangular geocoordinate set>
-- selectMeterIDsForArea -91.40624523544129 , 40.539939877519885 , -83.474116329193464 , 37.117668162290165

-- =============================================
ALTER PROCEDURE [selectMeterIDsForArea]
    -- Add the parameters for the stored procedure here
    @ax as float,
    @ay as float,
    @bx as float,
    @by as float,
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

        SELECT distinct [dbo].[Meter].[ID] as TheMeterID from [dbo].[Meter] inner join [dbo].[MeterLocation] on [dbo].[Meter].[MeterLocationID] = [dbo].[MeterLocation].[ID]

        where ( [dbo].[MeterLocation].[Latitude] between @by and @ay and [dbo].[MeterLocation].[Longitude] between @ax and @bx )
        and [dbo].[Meter].[ID] in (select * from authMeters(@username))

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for Day>
-- =============================================

--[selectMeterLocations] '04/07/2008'

ALTER PROCEDURE [selectMeterLocations]
    @EventDate DateTime
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @thedate DATE = CAST(@EventDate AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        (
            SELECT COUNT(Event.ID)
            FROM
                Event JOIN
                EventType ON EventType.ID = Event.EventTypeID
            WHERE
                CAST([StartTime] AS DATE) = @thedate AND
                Event.MeterID = Meter.ID
        ) AS Event_Count
        FROM
            Meter JOIN
            MeterLocation on Meter.MeterLocationID = MeterLocation.ID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 03, 2015>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- =============================================
-- [selectMeterLocationsBreakers] '09/14/2014', '10/20/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- [selectMeterLocationsBreakers] '09/30/2014', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- [selectMeterLocationsBreakers] '09/30/2014 06:00 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- [selectMeterLocationsBreakers] '09/30/2014 06:43 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- [selectMeterLocationsBreakers] '09/30/2014 06:43:57 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'second'
-- =============================================
ALTER PROCEDURE [selectMeterLocationsBreakers]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @startDate DATETIME = @EventDateFrom
    DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))


    IF @context = 'day'
    BEGIN
        SET @endDate = DATEADD(DAY, 1, @startDate)
    END

    if @context = 'hour'
    BEGIN
        SET @endDate = DATEADD(HOUR, 1, @startDate)
    END

    if @context = 'minute'
    BEGIN
        SET @endDate = DATEADD(MINUTE, 1, @startDate)
    END

    if @context = 'second'
    BEGIN
        SET @endDate = DATEADD(SECOND, 1, @startDate)
    END

    DECLARE @PivotColumns NVARCHAR(MAX) = N''
    DECLARE @CountColumns NVARCHAR(MAX) = N''
    DECLARE @ReturnColumns NVARCHAR(MAX) = N''
    DECLARE @SQLStatement NVARCHAR(MAX) = N''

    create table #TEMP (Name varchar(max))
    insert into #TEMP SELECT Name FROM (Select Distinct Name FROM BreakerOperationType) as t

    SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(Name as varchar(max)), '') + '],'
    FROM #TEMP ORDER BY Name desc

    SELECT @CountColumns = @CountColumns + 'COALESCE([' + COALESCE(CAST(Name as varchar(20)), '') + '], 0) + '
    FROM #TEMP ORDER BY Name desc

    SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(Name as varchar(max)), '') + '], 0) AS [' + COALESCE(CAST(Name as varchar(max)), '') + '],'
    FROM #TEMP ORDER BY Name desc

    DROP TABLE #TEMP


    SET @SQLStatement =
    ' SELECT Meter.ID,
             Meter.Name,
             MeterLocation.Longitude,
             MeterLocation.Latitude,
             ' + SUBSTRING(@CountColumns,0, LEN(@CountColumns)) +' as Count,
             ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
    FROM
        Meter JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
        (
            SELECT MeterID,
                   COUNT(*) AS EventCount,
                   BreakerOperationType.Name as OperationType
            FROM BreakerOperation JOIN
                 Event ON BreakerOperation.EventID = Event.ID JOIN
                 EventType ON Event.EventTypeID = EventType.ID JOIN
                 BreakerOperationType ON BreakerOperation.BreakerOperationTypeID = BreakerOperationType.ID
            WHERE
                 TripCoilEnergized >= @startDate AND TripCoilEnergized < @endDate
            GROUP BY Event.MeterID, BreakerOperationType.Name
           ) as ed
           PIVOT(
                 SUM(ed.EventCount)
                 FOR ed.OperationType IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
           ) as pvt On pvt.MeterID = meter.ID
    WHERE
        Meter.ID in (select * from authMeters(@username)) AND
        Meter.ID IN (SELECT * FROM String_To_Int_Table( @MeterIds,  '',''))

    ORDER BY Meter.Name'

    print @SQLStatement
    exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterIds nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DATETIME ', @username = @username, @MeterIds = @MeterIds, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Aug 31, 2015>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- =============================================

--[selectMeterLocationsCompleteness] '05/07/2014' , '05/07/2014', 'jwalker'
ALTER PROCEDURE [selectMeterLocationsCompleteness]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @meterIds AS varchar(max)
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        (
            SELECT CAST(COALESCE(CAST(SUM(goodPoints) AS FLOAT) / NULLIF(CAST(SUM(expectedPoints) AS FLOAT), 0) * 100 , 0) AS INT)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS Count,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.ExpectedPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS ExpectedPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.GoodPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS GoodPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.LatchedPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS LatchedPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.UnreasonablePoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS UnreasonablePoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.NoncongruentPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS NoncongruentPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.DuplicatePoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS DuplicatePoints
        FROM
            Meter JOIN
            MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
        ORDER BY Meter.Name
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Aug 31, 2015>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- =============================================
--[selectMeterLocationsCorrectness] '08/14/2008' , '08/16/2008', 'jwalker'

ALTER PROCEDURE [selectMeterLocationsCorrectness]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        (
            SELECT CAST(COALESCE(CAST(SUM(goodPoints) AS FLOAT) / NULLIF(CAST(SUM(expectedPoints) AS FLOAT), 0) * 100 , 0) AS INT)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS Count,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.ExpectedPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS ExpectedPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.GoodPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS GoodPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.LatchedPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS LatchedPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.UnreasonablePoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS UnreasonablePoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.NoncongruentPoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS NoncongruentPoints,
        (
            SELECT COALESCE(SUM(MeterDataQualitySummary.DuplicatePoints), 0)
            FROM MeterDataQualitySummary
            WHERE MeterDataQualitySummary.MeterID = Meter.ID AND [Date] BETWEEN @startDate AND @endDate
        ) AS DuplicatePoints
        FROM
            Meter JOIN
            MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
        ORDER BY Meter.Name
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Update date: <07/08/2016>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- [selectMeterLocationsEvents] '04/07/2008' , '04/07/2014', 'External'
-- =============================================
ALTER PROCEDURE [selectMeterLocationsEvents]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max),
    @username as nvarchar(4000),
    @context as nvarchar(20)

AS
BEGIN

    SET NOCOUNT ON;
DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))


IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
END

if @context = 'second'
BEGIN
    SET @endDate = DATEADD(SECOND, 1, @startDate)
END


DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @CountColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

SELECT @PivotColumns = @PivotColumns + '[' + t.Name + '],'
FROM (Select Name FROM EventType) AS t

SELECT @CountColumns = @CountColumns + 'COALESCE([' + t.Name + '], 0) + '
FROM (Select Name FROM EventType) AS t


SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + t.Name + '], 0) AS [' + t.Name + '],'
FROM (Select Name FROM EventType) AS t

SET @SQLStatement =
' 
DECLARE @user varchar(max) = @username
DECLARE @ids varchar(max) = @MeterIds
DECLARE @start DateTime = @startDate
DECLARE @end DateTime = @endDate

SELECT Meter.ID, 
		 Meter.Name,
		 MeterLocation.Longitude,
		 MeterLocation.Latitude,
		 ' + SUBSTRING(@CountColumns,0, LEN(@CountColumns)) +' as Count,
		 ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
FROM 
    Meter JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
	(
		SELECT MeterID, 
			   COUNT(*) AS EventCount, 
			   EventType.Name as Name
			   
		FROM Event JOIN
			 EventType ON Event.EventTypeID = EventType.ID 
        WHERE 
			 StartTime >= @start AND StartTime < @end  
        GROUP BY Event.MeterID, EventType.Name 
       ) as ed 
	   PIVOT( 
	   		 SUM(ed.EventCount)
	   		 FOR ed.Name IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ') 
	   ) as pvt On pvt.MeterID = meter.ID
WHERE 
	Meter.ID in (select * from authMeters(@user)) AND 
	Meter.ID IN (SELECT * FROM String_To_Int_Table( @ids,  '',''))  

ORDER BY Meter.Name'

--print @startDate
--print @endDate
print @sqlstatement

exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterIds nvarchar(MAX), @startDate DATETIME, @endDate DATETIME', @username = @username, @MeterIds = @MeterIds, @startDate = @startDate, @endDate = @endDate
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- [selectMeterLocationsFaults] '08/05/2014', '08/20/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'custom'
-- [selectMeterLocationsFaults] '08/08/2014', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'day'
-- [selectMeterLocationsFaults] '08/08/2014 09:00 AM', '03/06/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'hour'
-- [selectMeterLocationsFaults] '08/08/2014 09:34 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'minute'
-- [selectMeterLocationsFaults] '08/08/2014 09:34:04 AM', '11/10/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'External', 'second'
-- =============================================
ALTER PROCEDURE [selectMeterLocationsFaults]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @meterIds AS varchar(max),
    @username as nvarchar(4000),
    @context as nvarchar(20)

AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATETIME = @EventDateFrom
DECLARE @endDate DATETIME = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))


IF @context = 'day'
BEGIN
    SET @endDate = DATEADD(DAY, 1, @startDate)
END

if @context = 'hour'
BEGIN
    SET @endDate = DATEADD(HOUR, 1, @startDate)
END

if @context = 'minute'
BEGIN
    SET @endDate = DATEADD(MINUTE, 1, @startDate)
END

if @context = 'second'
BEGIN
    SET @endDate = DATEADD(SECOND, 1, @startDate)
END


DECLARE @PivotColumns NVARCHAR(MAX) = N''
DECLARE @CountColumns NVARCHAR(MAX) = N''
DECLARE @ReturnColumns NVARCHAR(MAX) = N''
DECLARE @SQLStatement NVARCHAR(MAX) = N''

SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '],'
FROM (Select Distinct Line.VoltageKV
        FROM Line) AS t

SELECT @CountColumns = @CountColumns + 'COALESCE([' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '], 0) + '
FROM (Select Distinct Line.VoltageKV
        FROM Line) AS t

SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '], 0) AS [' + COALESCE(CAST(t.VoltageKV as varchar(5)), '') + '],'
FROM (Select Distinct Line.VoltageKV
        FROM Line) AS t


SET @SQLStatement =
' SELECT Meter.ID,
         Meter.Name,
         MeterLocation.Longitude,
         MeterLocation.Latitude,
         ' + SUBSTRING(@CountColumns,0, LEN(@CountColumns)) +' as Count,
         ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
FROM
    Meter JOIN
    MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
    (
        SELECT MeterID,
               COUNT(*) AS EventCount,
               VoltageKV
        FROM Event JOIN
             EventType ON Event.EventTypeID = EventType.ID JOIN
             Line ON Event.LineID = Line.ID
        WHERE
             StartTime >= @startDate AND StartTime < @endDate AND
             EventType.Name = ''Fault''
        GROUP BY Event.MeterID, VoltageKV
       ) as ed
       PIVOT(
             SUM(ed.EventCount)
             FOR ed.VoltageKV IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
       ) as pvt On pvt.MeterID = meter.ID
    WHERE
        Meter.ID in (select * from authMeters(@username)) AND
        Meter.ID IN (SELECT * FROM String_To_Int_Table( @MeterIds,  '',''))

ORDER BY Meter.Name'

print @SQLStatement
exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterIds nvarchar(MAX), @startDate DATETIME, @endDate DATETIME, @EventDateFrom DATETIME ', @username = @username, @MeterIds = @MeterIds, @startDate = @startDate, @endDate = @endDate, @EventDateFrom = @EventDateFrom

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- [selectMeterLocationsMaximumSwell] '08/22/2014' , '09/21/2014', 'jwalker'
-- =============================================

ALTER PROCEDURE [selectMeterLocationsMaximumSwell]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max)
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        CAST(COALESCE((
            SELECT (10.0/9.0) * ((MAX([PerUnitMagnitude]) - 1.1)) * 100
            FROM
                Disturbance  JOIN
                Event ON Disturbance.EventID = Event.ID JOIN
                EventType ON EventType.ID = Event.EventTypeID AND EventType.Name = 'Swell'
            WHERE
                CAST(Event.StartTime AS DATE) BETWEEN @startDate AND @endDate AND
                Event.MeterID = Meter.ID AND
                PerUnitMagnitude IS NOT NULL AND
                PerUnitMagnitude >= 1.1
        ), 0) AS INT) AS Count
    FROM
        Meter JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
    ORDER BY Meter.Name

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, May 27, 2014>
-- Description: <Description, Selects Meter Identification Data, Event Count and Location for DateRange>
-- [selectMeterLocationsMinimumSags] '09/07/2014' , '09/07/2014', 'jwalker'
-- =============================================

ALTER PROCEDURE [selectMeterLocationsMinimumSags]
    @EventDateFrom DATETIME,
    @EventDateTo DATETIME,
    @meterIds AS varchar(max)
AS
BEGIN

    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)

    SELECT
        Meter.ID,
        Meter.Name,
        MeterLocation.Longitude,
        MeterLocation.Latitude,
        CAST(COALESCE((
            SELECT (10.0/8.0) * (0.9 - (MIN(PerUnitMagnitude))) * 100
            FROM
                Disturbance JOIN
                Event ON Disturbance.EventID = Event.ID JOIN
                EventType ON EventType.ID = Event.EventTypeID AND EventType.Name = 'Sag'
            WHERE
                CAST(Event.StartTime AS DATE) BETWEEN @startDate AND @endDate AND
                Event.MeterID = Meter.ID AND
                PerUnitMagnitude IS NOT NULL AND PerUnitMagnitude <= 0.9
        ), 0) AS INT) AS Count
    FROM
        Meter JOIN
        MeterLocation ON Meter.MeterLocationID = MeterLocation.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
    ORDER BY Meter.Name

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 24, 2014>
-- Description: <Description, Selects Meter Identification Data, Alarm Count and Location for Day>
-- [selectMeterLocationsTrending] '08/19/2008','08/20/2008', 'external'
-- =============================================

ALTER PROCEDURE [selectMeterLocationsTrending]
    @EventDateFrom DateTime,
    @EventDateTo DateTime,
    @meterIds AS varchar(max)
AS
BEGIN

    SET NOCOUNT ON;

        declare @thedatefrom as Date;
        declare @thedateto as Date;

        set @thedatefrom = CAST(@EventDateFrom as Date);
        set @thedateto = CAST(@EventDateTo as Date);

        SELECT
            [dbo].[Meter].[ID],
            [dbo].[Meter].[Name],
            [dbo].[MeterLocation].[Longitude],
            [dbo].[MeterLocation].[Latitude],
            COALESCE(Alarm, 0) as Alarm,
            COALESCE(Offnormal, 0) As Offnormal,
            COALESCE(AlarmCount, 0) As AlarmCount
        FROM
            Meter JOIN
            MeterLocation ON Meter.MeterLocationID = MeterLocation.ID LEFT OUTER JOIN
            (
                SELECT
                    MeterID,
                    Alarm + Offnormal as AlarmCount,
                    Alarm,
                    Offnormal
                FROM
                    (
                        SELECT
                            Channel.MeterID,
                            AlarmType.Name
                        FROM
                            AlarmType JOIN
                            ChannelAlarmSummary ON ChannelAlarmSummary.AlarmTypeID = AlarmType.ID JOIN
                            Channel ON Channel.ID = ChannelAlarmSummary.ChannelID
                        WHERE ChannelAlarmSummary.Date BETWEEN @thedatefrom AND @thedateto

                    ) AS AlarmCodes
                    PIVOT
                    (
                        COUNT(Name)
                        FOR Name IN (Alarm, Offnormal)
                    ) AS PivotTable
        ) AS AlarmCount ON AlarmCount.MeterID = Meter.ID
        WHERE Meter.ID IN (SELECT * FROM String_To_Int_Table(@meterIds, ','))
       ORDER BY Meter.Name

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Feb 25, 2015>
-- Description: <Description, Selects meters>
-- selectMeters 'External'
-- =============================================
ALTER PROCEDURE [selectMeters]
        @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;
        SELECT distinct [dbo].[Meter].[ID] as id, [dbo].[Meter].[Name]
        from [dbo].[Meter] where [dbo].[Meter].[ID] in (Select * from authMeters(@username) )
        order by [dbo].[Meter].[Name]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Phase for Meter, MeasurementType, MeasurementCharacteristic for date >
-- selectPhase '04/07/2008', 61 , 1 , 1

-- =============================================
ALTER PROCEDURE [selectPhase]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @Type as int,
    @Characteristic as int

AS
BEGIN

    SET NOCOUNT ON;

    declare @theDate as Date

    set @theDate = CAST(@EventDate as Date)

  SELECT distinct [dbo].[Phase].[ID] as value,  [dbo].[Phase].[Name] as text from [dbo].[Phase]
    join [dbo].[Channel] on [dbo].[Channel].[PhaseID] = [dbo].[Phase].[ID]
    join [dbo].[DailyTrendingSummary] on [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[Channel].[ID] and [DailyTrendingSummary].[Date] = @theDate
    join [dbo].[Meter] on [dbo].[Channel].[MeterID] = [dbo].[Meter].[ID] and [dbo].[Meter].[ID] = @MeterID
    join [dbo].[MeasurementType] on [dbo].[Channel].[MeasurementTypeID] = @Type
    join [dbo].[MeasurementCharacteristic] on [dbo].[Channel].[MeasurementCharacteristicID] = @Characteristic
    order by [dbo].[Phase].[ID]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Mar 02, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for @NumberOfDays days back>
-- selectPowerLineClasses 'jwalker'
-- =============================================
ALTER PROCEDURE [selectPowerLineClasses]
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

select distinct VoltageKV as class from [dbo].[Line]
join Channel on Line.ID = Channel.LineID
join Meter on Channel.MeterID = Meter.ID
where Meter.ID in (select * from authMeters(@username))

order by VoltageKV Desc

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Sep 17, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSiteChannelCompletenessDetailsByDate2 '09/17/2014', '77'
-- =============================================
ALTER PROCEDURE [selectSiteChannelCompletenessDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    select
    Distinct [dbo].[Channel].[ID] as channelid,
    [dbo].[Channel].[Name] as channelname,
    @EventDate as date,
    [dbo].[Meter].[ID] as meterid,
    [dbo].[MeasurementType].[Name] as measurementtype,
    [dbo].[MeasurementCharacteristic].[Name] as characteristic,
    [dbo].[Phase].[Name] as phasename,

    COALESCE(CAST( cast(LatchedPoints as float) / NULLIF(cast(expectedPoints as float),0) as float),0) * 100 as Latched,
    COALESCE(CAST( cast(UnreasonablePoints as float) / NULLIF(cast(expectedPoints as float),0) as float),0) * 100 as Unreasonable,
    COALESCE(CAST( cast(NoncongruentPoints as float) / NULLIF(cast(expectedPoints as float),0) as float),0) * 100 as Noncongruent,
    COALESCE(CAST( cast(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints as float) / NULLIF(cast(expectedPoints as float),0) as float),0) * 100 as completeness

    from [dbo].[ChannelDataQualitySummary]
    join [dbo].[Channel] on [dbo].[ChannelDataQualitySummary].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[Meter] on [dbo].[Channel].[MeterID] = @MeterID
    join [dbo].[MeasurementType] on [dbo].[MeasurementType].[ID] = [dbo].[Channel].[MeasurementTypeID]
    join [dbo].[MeasurementCharacteristic] on [dbo].[MeasurementCharacteristic].[ID] = [dbo].[Channel].[MeasurementCharacteristicID]
    join [dbo].[Phase] on [dbo].[Phase].[ID] = [dbo].[Channel].[PhaseID]
    where [dbo].[ChannelDataQualitySummary].[Date] = @EventDate and [dbo].[Meter].[ID] = @MeterID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Sep 1, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSiteChannelDataQualityDetailsByDate '09/01/2008', '1'

-- =============================================
ALTER PROCEDURE [selectSiteChannelDataQualityDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    select
    Distinct [dbo].[Channel].[ID] as channelid,
    @EventDate as date,
    [dbo].[Channel].[Name] as channelname,
    [dbo].[Meter].[ID] as meterid,
    [dbo].[MeasurementType].[Name] as measurementtype,
    [dbo].[MeasurementCharacteristic].[Name] as characteristic,
    [dbo].[Phase].[Name] as phasename,
    [dbo].[ChannelDataQualitySummary].[ExpectedPoints] as ExpectedPoints,
    [dbo].[ChannelDataQualitySummary].[GoodPoints] as GoodPoints,
    [dbo].[ChannelDataQualitySummary].[LatchedPoints] as LatchedPoints,
    [dbo].[ChannelDataQualitySummary].[UnreasonablePoints] as UnreasonablePoints,
    [dbo].[ChannelDataQualitySummary].[NoncongruentPoints] as NoncongruentPoints,
    [dbo].[ChannelDataQualitySummary].[DuplicatePoints] as DuplicatePoints
    from [dbo].[ChannelDataQualitySummary]
    join [dbo].[Channel] on [dbo].[ChannelDataQualitySummary].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[Meter] on [dbo].[Channel].[MeterID] = @MeterID
    join [dbo].[MeasurementType] on [dbo].[MeasurementType].[ID] = [dbo].[Channel].[MeasurementTypeID]
    join [dbo].[MeasurementCharacteristic] on [dbo].[MeasurementCharacteristic].[ID] = [dbo].[Channel].[MeasurementCharacteristicID]
    join [dbo].[Phase] on [dbo].[Phase].[ID] = [dbo].[Channel].[PhaseID]
    where [dbo].[ChannelDataQualitySummary].[Date] = @EventDate and [dbo].[Meter].[ID] = @MeterID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSiteLinesDetailsByDate '11/08/16', '1351', 'day'
-- selectSiteLinesDetailsByDate '11/08/16 03:00 PM', '1351', 'hour'
-- selectSiteLinesDetailsByDate '11/08/16 03:30 PM', '1351', 'minute'
-- selectSiteLinesDetailsByDate '11/08/16 03:30:55 PM', '1351', 'second'
-- =============================================
ALTER PROCEDURE [selectSiteLinesDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DATETIME
    DECLARE @endDate DATETIME
	
	IF @context = '180d'
    BEGIN
		SET @startDate = DATEADD(HOUR, -180, @EventDate)
		SET @endDate = @EventDate
    END

	IF @context = '90d'
    BEGIN
		SET @startDate = DATEADD(DAY, -90, @EventDate)
		SET @endDate = @EventDate
    END

    IF @context = '30d'
    BEGIN
		SET @startDate = DATEADD(DAY, -30, @EventDate)
		SET @endDate = @EventDate
    END

    IF @context = '7d'
    BEGIN
		SET @startDate = DATEADD(DAY, -7, @EventDate)
		SET @endDate = @EventDate
    END

	IF @context = '24h'
	BEGIN
		SET @startDate = DATEADD(HOUR, -24, @EventDate)
		SET @endDate = @EventDate
	END

    IF @context = 'day'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(DAY, 1, @startDate)
    END

    if @context = 'hour'
    BEGIN
        SET @startDate = DATEADD(HOUR, DATEDIFF(HOUR, 0, @EventDate), 0)
        SET @endDate = DATEADD(HOUR, 1, @startDate)
    END

    if @context = 'minute'
    BEGIN
        SET @startDate = DATEADD(MINUTE, DATEDIFF(MINUTE, 0, @EventDate), 0)
        SET @endDate = DATEADD(MINUTE, 1, @startDate)
    END

    if @context = 'second'
    BEGIN
        DECLARE @tempDate DATETIME = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @startDate = DATEADD(SECOND, DATEDIFF(SECOND, @tempDate, @EventDate), @tempDate)
        SET @endDate = DATEADD(SECOND, 1, @startDate)
    END


    DECLARE @localEventDate DATE = CAST(@EventDate AS DATE)
    DECLARE @localMeterID INT = CAST(@MeterID AS INT)

    ; WITH cte AS
    (
        SELECT
            Event.LineID AS thelineid,
            Event.ID AS theeventid,
            EventType.Name AS theeventtype,
            CAST(Event.StartTime AS VARCHAR(26)) AS theinceptiontime,
            MeterLine.LineName + ' ' + [Line].[AssetKey] AS thelinename,
            Line.VoltageKV AS voltage,
            COALESCE(FaultSummary.FaultType, Phase.Name, '') AS thefaulttype,
            CASE WHEN FaultSummary.Distance = '-1E308' THEN 'NaN' ELSE COALESCE(CAST(CAST(FaultSummary.Distance AS DECIMAL(16, 4)) AS NVARCHAR(19)) + ' mi', '') END AS thecurrentdistance,
            dbo.EventHasImpactedComponents(Event.ID) AS pqiexists,
            Event.StartTime,
            CASE EventType.Name
                WHEN 'Sag' THEN ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY Magnitude, Disturbance.StartTime, IsSelectedAlgorithm DESC, IsSuppressed, Inception)
                WHEN 'Interruption' THEN ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY Magnitude, Disturbance.StartTime, IsSelectedAlgorithm DESC, IsSuppressed, Inception)
                WHEN 'Swell' THEN ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY Magnitude DESC, Disturbance.StartTime, IsSelectedAlgorithm DESC, IsSuppressed, Inception)
                WHEN 'Fault' THEN ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY IsSelectedAlgorithm DESC, IsSuppressed, IsValid DESC, Inception)
                ELSE ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY Event.ID)
            END AS RowPriority,
            (SELECT COUNT(*) FROM Event as EventCount WHERE EventCount.StartTime BETWEEN DateAdd(SECOND, -5, Event.StartTime) and  DateAdd(SECOND, 5, Event.StartTime)) as SimultaneousCount,
            (SELECT COUNT(*) FROM Event as EventCount WHERE EventCount.LineID = Event.LineID AND EventCount.StartTime BETWEEN DateAdd(Day, -60, Event.StartTime) and  Event.StartTime) as SixtyDayCount,
            Event.UpdatedBy,
            (SELECT COUNT(*) FROM EventNote WHERE EventID = Event.ID) as Note
        FROM
            Event JOIN
            EventType ON Event.EventTypeID = EventType.ID LEFT OUTER JOIN
            Disturbance ON Disturbance.EventID = Event.ID LEFT OUTER JOIN
            FaultSummary ON FaultSummary.EventID = Event.ID  LEFT OUTER JOIN
            Phase ON Disturbance.PhaseID = Phase.ID JOIN
            Meter ON Meter.ID = @MeterID JOIN
            Line ON Event.LineID = Line.ID JOIN
            MeterLine ON MeterLine.MeterID = @MeterID AND MeterLine.LineID = Line.ID
        WHERE
            Event.StartTime >= @startDate AND Event.StartTime < @endDate AND
            Event.MeterID = @localMeterID AND
            (Phase.ID IS NULL OR Phase.Name <> 'Worst')
    )
    SELECT
        thelineid,
        theeventid,
        theeventtype,
        theinceptiontime,
        thelinename,
        voltage,
        thefaulttype,
        thecurrentdistance,
        pqiexists,
        SimultaneousCount,
        SixtyDayCount,
        UpdatedBy,
        Note
    INTO #temp
    FROM cte
    WHERE RowPriority = 1
    ORDER BY StartTime

    DECLARE @sql NVARCHAR(MAX)
    SELECT @sql = COALESCE(@sql + ',dbo.' + HasResultFunction + '(theeventid) AS ' + ServiceName, 'dbo.' + HasResultFunction + '(theeventid) AS ' + ServiceName)
    FROM EASExtension

    DECLARE @serviceList NVARCHAR(MAX)
    SELECT @serviceList = COALESCE(@serviceList + ',' + ServiceName, ServiceName)
    FROM EASExtension
    Set @serviceList = '''' + @serviceList + ''''

    SET @sql = COALESCE('SELECT *,' + @sql + ', '+ @ServiceList +'as ServiceList FROM #temp', 'SELECT *, '''' as ServiceList FROM #temp')
    EXEC sp_executesql @sql

    DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 7, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- [selectSitesBreakersDetailsByDate] '09/30/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'day'
-- [selectSitesBreakersDetailsByDate] '09/30/2014 06:00 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'hour'
-- [selectSitesBreakersDetailsByDate] '09/30/2014 06:43 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'minute'
-- [selectSitesBreakersDetailsByDate] '09/30/2014 06:43:57 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'second'
-- =============================================
ALTER PROCEDURE [selectSitesBreakersDetailsByDate]
    @EventDate AS DATETIME,
    @MeterID AS NVARCHAR(MAX),
    @username AS NVARCHAR(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DateTime
    DECLARE @endDate DateTime

    IF @context = 'day'
    BEGIN
        SET @startDate = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @endDate = DATEADD(DAY, 1, @startDate)
    END

    if @context = 'hour'
    BEGIN
        SET @startDate = DATEADD(HOUR, DATEDIFF(HOUR, 0, @EventDate), 0)
        SET @endDate = DATEADD(HOUR, 1, @startDate)
    END

    if @context = 'minute'
    BEGIN
        SET @startDate = DATEADD(MINUTE, DATEDIFF(MINUTE, 0, @EventDate), 0)
        SET @endDate = DATEADD(MINUTE, 1, @startDate)
    END

    if @context = 'second'
    BEGIN
        DECLARE @tempDate DATETIME = DATEADD(DAY, DATEDIFF(DAY, 0, @EventDate), 0)
        SET @startDate = DATEADD(SECOND, DATEDIFF(SECOND, @tempDate, @EventDate), @tempDate)
        SET @endDate = DATEADD(SECOND, 1, @startDate)
    END

    SELECT
        Meter.ID AS meterid,
        Event.ID AS theeventid,
        EventType.Name AS eventtype,
        BreakerOperation.ID AS breakeroperationid,
        CAST(CAST(BreakerOperation.TripCoilEnergized AS TIME) AS NVARCHAR(100)) AS energized,
        BreakerOperation.BreakerNumber AS breakernumber,
        MeterLine.LineName AS linename,
        Phase.Name AS phasename,
        CAST(BreakerOperation.BreakerTiming AS DECIMAL(16,5)) AS timing,
        CAST(BreakerOperation.StatusTiming AS DECIMAL(16,5)) AS statustiming,
        BreakerOperation.BreakerSpeed AS speed,
        BreakerOperation.StatusBitChatter AS chatter,
        BreakerOperation.DcOffsetDetected AS dcoffset,
        BreakerOperationType.Name AS operationtype
    FROM
        BreakerOperation JOIN
        Event ON BreakerOperation.EventID = Event.ID JOIN
        EventType ON EventType.ID = Event.EventTypeID JOIN
        Meter ON Meter.ID = Event.MeterID JOIN
        Line ON Line.ID = Event.LineID JOIN
        MeterLine ON MeterLine.LineID = Event.LineID AND MeterLine.MeterID = Meter.ID JOIN
        BreakerOperationType ON BreakerOperation.BreakerOperationTypeID = BreakerOperationType.ID JOIN
        Phase ON BreakerOperation.PhaseID = Phase.ID
    WHERE
        TripCoilEnergized >= @startDate AND TripCoilEnergized < @endDate AND
        Meter.ID IN (SELECT * FROM  dbo.String_to_int_table(@MeterID, ',')) AND
        Meter.ID IN (select * from authMeters(@username))
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesCompletenessDetailsByDate '07/19/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,','jwalker'
-- selectSitesCompletenessDetailsByDate2 '09/03/2014', '108,109,86,87,110,118,13,17,167,168,77,78,79,80,70,46,169,185,186,40,6,170,88,89,52,192,15,16,91,92,93,94,95,96,97,28,98,99,100,101,102,171,57,172,125,173,63,19,104,174,55,105,106,107,103,111,112,113,60,53,160,114,115,116,117,68,12,58,54,8,59,18,20,9,193,119,120,81,164,121,175,156,157,176,177,11,122,123,21,65,1,41,39,23,51,127,128,129,130,165,76,131,132,133,134,135,136,137,14,124,45,47,73,64,2,138,139,140,141,142,143,82,83,62,50,144,145,56,30,42,146,147,148,149,150,151,32,152,126,74,67,10,66,22,178,179,29,180,48,181,153,154,155,194,24,43,34,4,69,37,158,26,182,36,159,161,162,163,71,166,25,31,44,49,72,61,75,187,188,189,190,191,3,84,85,7,195,90,183,27,196,184,35,33,197,198,199,200,201,38,5,','jwalker'
-- selectSitesCompletenessDetailsByDate '09/17/2008', '86', 'jwalker'
-- =============================================
ALTER PROCEDURE [selectSitesCompletenessDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate AS DATETIME,
    @MeterID AS NVARCHAR(MAX),
    @username AS NVARCHAR(4000)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @thedate DATE = CAST(@EventDate AS DATE)
    DECLARE @MeterIDs TABLE (ID INT);

    INSERT INTO @MeterIDs(ID)
    SELECT Value FROM dbo.String_to_int_table(@MeterID, ',')
    WHERE Value IN (SELECT * FROM authMeters(@username));

    DECLARE @TempTable TABLE (themeterid INT, thesite VARCHAR(100), thecount FLOAT, thename VARCHAR(100));

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE((
                SELECT CAST(CAST((GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints) AS FLOAT) / NULLIF(CAST(expectedPoints AS FLOAT), 0) AS FLOAT) AS completenessPercentage
                FROM MeterDataQualitySummary
                WHERE
                    MeterID = Meter.ID AND
                    [Date] = @thedate
            )
        , 0)) AS thecount,
        'Completeness' as thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE((
                SELECT CAST(NULLIF(CAST(expectedPoints AS FLOAT), 0) AS FLOAT) AS completenessPercentage
                FROM MeterDataQualitySummary
                WHERE
                    MeterID = Meter.ID AND
                    [Date] = @thedate
            )
        , 0)) AS thecount,
        'Expected' AS thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE((
                SELECT CAST(CAST((GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints + DuplicatePoints) AS FLOAT) / NULLIF(CAST(expectedPoints AS FLOAT), 0) AS FLOAT) AS completenessPercentage
                FROM MeterDataQualitySummary
                WHERE
                    MeterID = Meter.ID AND
                    [Date] = @theDate
            )
        , 0)) AS thecount,
        'Received' AS thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE((
                SELECT CAST(CAST((DuplicatePoints) AS FLOAT) / NULLIF(CAST(expectedPoints AS FLOAT), 0) AS FLOAT) AS completenessPercentage
                FROM MeterDataQualitySummary
                WHERE
                    MeterID = Meter.ID AND
                    [Date] = @thedate
            )
        , 0)) AS thecount,
        'Duplicate' AS thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    DECLARE @composite TABLE (theeventid INT, themeterid INT, thesite VARCHAR(100), Expected FLOAT, Received FLOAT, Duplicate FLOAT, Completeness FLOAT);

    DECLARE @sitename VARCHAR(100)
    DECLARE @themeterid INT
    DECLARE @theeventid INT

    DECLARE site_cursor CURSOR FOR SELECT DISTINCT themeterid, thesite FROM @TempTable

    OPEN site_cursor

    FETCH NEXT FROM site_cursor INTO @themeterid , @sitename

    WHILE @@FETCH_STATUS = 0
    BEGIN
        INSERT @composite VALUES(
            (
                SELECT TOP 1 MeterDataQualitySummary.ID
                FROM MeterDataQualitySummary
                WHERE
                    MeterDataQualitySummary.MeterID = @themeterid AND
                    CAST([Date] as Date) = @thedate
            ),
            @themeterid,
            @sitename,
            (SELECT thecount * 100 FROM @TempTable WHERE thename = 'Expected' AND thesite = @sitename),
            (SELECT thecount * 100 FROM @TempTable WHERE thename = 'Received' AND thesite = @sitename),
            (SELECT thecount * 100 FROM @TempTable WHERE thename = 'Duplicate' AND thesite = @sitename),
            (SELECT thecount * 100 FROM @TempTable WHERE thename = 'Completeness' AND thesite = @sitename)
        )

        FETCH NEXT FROM site_cursor INTO @themeterid , @sitename
    END

    CLOSE site_cursor;
    DEALLOCATE site_cursor;

    SELECT * FROM @composite
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesCorrectnessDetailsByDate '07/19/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,','External'
-- selectSitesCorrectnessDetailsByDate '09/03/2007', '108,109,86,87,110,118,13,17,167,168,77,78,79,80,70,46,169,185,186,40,6,170,88,89,52,192,15,16,91,92,93,94,95,96,97,28,98,99,100,101,102,171,57,172,125,173,63,19,104,174,55,105,106,107,103,111,112,113,60,53,160,114,115,116,117,68,12,58,54,8,59,18,20,9,193,119,120,81,164,121,175,156,157,176,177,11,122,123,21,65,1,41,39,23,51,127,128,129,130,165,76,131,132,133,134,135,136,137,14,124,45,47,73,64,2,138,139,140,141,142,143,82,83,62,50,144,145,56,30,42,146,147,148,149,150,151,32,152,126,74,67,10,66,22,178,179,29,180,48,181,153,154,155,194,24,43,34,4,69,37,158,26,182,36,159,161,162,163,71,166,25,31,44,49,72,61,75,187,188,189,190,191,3,84,85,7,195,90,183,27,196,184,35,33,197,198,199,200,201,38,5,','External'

-- =============================================
ALTER PROCEDURE [selectSitesCorrectnessDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @thedate DATE = CAST(@EventDate AS DATE)
    DECLARE @MeterIDs TABLE (ID INT);

    INSERT INTO @MeterIDs(ID)
    SELECT Value
    FROM dbo.String_to_int_table(@MeterID, ',')
    WHERE Value IN (SELECT * FROM authMeters(@username));

    DECLARE @TempTable TABLE (themeterid INT, thesite VARCHAR(100), thecount FLOAT, thename VARCHAR(100));

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE(ROUND(CAST(SUM(LatchedPoints) AS FLOAT) / NULLIF(CAST(SUM(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints) AS FLOAT), 0) * 100 , 0), 0) AS correctnessPercentage
            FROM MeterDataQualitySummary
            WHERE
                MeterID = Meter.ID AND
                [Date] = @thedate
        ) AS thecount,
        'Latched' as thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    INSERT INTO @TempTable (themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE(ROUND(CAST(SUM(UnreasonablePoints) AS FLOAT) / NULLIF(CAST(SUM(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints) AS FLOAT), 0) * 100 ,0), 0) AS correctnessPercentage
            FROM MeterDataQualitySummary
            WHERE
                MeterID = [dbo].[Meter].[ID] AND
                [Date] = @thedate
        ) AS thecount,
        'Unreasonable' AS thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    INSERT INTO @TempTable(themeterid, thesite , thecount , thename)
    SELECT
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        (
            SELECT COALESCE(ROUND(CAST(SUM(NoncongruentPoints) AS FLOAT) / NULLIF(CAST(SUM(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints) AS FLOAT), 0) * 100 , 0), 0) AS correctnessPercentage
            FROM MeterDataQualitySummary
            WHERE
                MeterID = Meter.ID AND
                [Date] = @thedate
        ) AS thecount,
        'Noncongruent' AS thename
    FROM
        MeterDataQualitySummary JOIN
        Meter ON Meter.ID = MeterDataQualitySummary.MeterID
    WHERE
        MeterID IN (SELECT * FROM @MeterIDs) AND
        CAST([Date] AS DATE) = @thedate

    DECLARE @composite TABLE (theeventid INT, themeterid INT, thesite VARCHAR(100), Latched FLOAT, Unreasonable FLOAT, Noncongruent FLOAT, Correctness FLOAT);

    DECLARE @sitename VARCHAR(100)
    DECLARE @themeterid INT
    DECLARE @theeventid INT

    DECLARE site_cursor CURSOR FOR SELECT DISTINCT themeterid, thesite FROM @TempTable

    OPEN site_cursor

    FETCH NEXT FROM site_cursor INTO @themeterid, @sitename

    WHILE @@FETCH_STATUS = 0
    BEGIN
        INSERT INTO @composite VALUES(
            (
                SELECT TOP 1 MeterDataQualitySummary.ID
                FROM MeterDataQualitySummary
                WHERE
                    MeterDataQualitySummary.MeterID = @themeterid AND
                    CAST([Date] AS DATE) = @theDate
            ),
            @themeterid,
            @sitename,
            (SELECT thecount FROM @TempTable WHERE thename = 'Latched' AND thesite = @sitename),
            (SELECT thecount FROM @TempTable WHERE thename = 'Unreasonable' AND thesite = @sitename),
            (SELECT thecount FROM @TempTable WHERE thename = 'Noncongruent' AND thesite = @sitename),
             (
                    SELECT 100.0 * CAST(GoodPoints AS FLOAT) / CAST(NULLIF(GoodPoints + LatchedPoints + UnreasonablePoints + NoncongruentPoints, 0) AS FLOAT) AS Correctness
                    FROM MeterDataQualitySummary
                    WHERE CAST([Date] AS DATE) = @theDate AND MeterID = @themeterid
             )
        )

        FETCH NEXT FROM site_cursor INTO @themeterid , @sitename
    END

    CLOSE site_cursor;
    DEALLOCATE site_cursor;

    SELECT * FROM @composite
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Billy Ernest>
-- Create date: <Create Date, Mar 06, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesEventsDetailsByDate '11/08/2016', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'day'
-- selectSitesEventsDetailsByDate '11/08/2016 03:00 PM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'hour'
-- selectSitesEventsDetailsByDate '11/08/2016 03:37 PM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'minute'

-- =============================================

ALTER PROCEDURE [selectSitesEventsDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DateTime = @EventDate
    DECLARE @endDate DateTime

    if @context = 'day'
        SET @endDate = DATEADD(DAY, 1, @startDate);
    if @context = 'hour'
        SET @endDate = DATEADD(HOUR, 1, @startDate);
    if @context = 'minute'
        SET @endDate = DATEADD(MINUTE, 1, @startDate);

	if @context = 'second'
		SET @endDate = DATEADD(SECOND,1,@startDate);

    DECLARE @PivotColumns NVARCHAR(MAX) = N''
    DECLARE @ReturnColumns NVARCHAR(MAX) = N''
    DECLARE @SQLStatement NVARCHAR(MAX) = N''

    SELECT @PivotColumns = @PivotColumns + '[' + COALESCE(CAST(t.Name as varchar(max)), '') + '],'
    FROM (Select Name FROM EventType) AS t

    SELECT @ReturnColumns = @ReturnColumns + ' COALESCE([' + COALESCE(CAST(t.Name as varchar(max)), '') + '], 0) AS [' + COALESCE(CAST(t.Name as varchar(max)), '') + '],'
    FROM (Select Name FROM EventType) AS t

    SET @SQLStatement =
    ' SELECT (SELECT TOP 1 ID FROM Event WHERE MeterID = pvt.MeterID AND StartTime >= @startDate AND StartTime < @endDate)
             EventID,
             MeterID,
             Site,
             ' + SUBSTRING(@ReturnColumns,0, LEN(@ReturnColumns)) + '
     FROM (
        SELECT
            Event.MeterID, COUNT(*) AS EventCount, EventType.Name, Meter.Name as Site
            FROM Event JOIN
            EventType ON Event.EventTypeID = EventType.ID JOIN
            Meter ON Event.MeterID = Meter.ID
           WHERE
                MeterID in (select * from authMeters(@username)) AND MeterID IN (SELECT * FROM String_To_Int_Table( @MeterID,  '','')) AND
                StartTime >= @startDate AND StartTime < @endDate
           GROUP BY Event.MeterID,Meter.Name,EventType.Name
           ) as ed
     PIVOT(
            SUM(ed.EventCount)
            FOR ed.Name IN(' + SUBSTRING(@PivotColumns,0, LEN(@PivotColumns)) + ')
     ) as pvt
     ORDER BY MeterID '

    print @startDate
    print @endDate
    print @sqlstatement
    exec sp_executesql @SQLStatement, N'@username nvarchar(4000), @MeterID nvarchar(MAX), @startDate DATETIME, @endDate DATETIME ', @username = @username, @MeterID = @MeterID, @startDate = @startDate, @endDate = @endDate
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 23, 2014>
-- Description: <Description, Selects Events for a set of sites by Date Range>
-- =============================================
ALTER PROCEDURE [selectSitesEventsDetailsByDateRange]
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
    DECLARE @endDate DATE = CAST(@EventDateTo AS DATE)
    DECLARE  @MeterIDs TABLE (ID INT);

    INSERT INTO @MeterIDs(ID)
    SELECT Value
    FROM dbo.String_to_int_table(@MeterID, ',')
    WHERE Value IN (SELECT * FROM authMeters(@username));

    SELECT
        CAST(CAST(Event.StartTime AS DATETIME2(7)) AS VARCHAR(26)) AS starttime,
        CAST(CAST(Event.EndTime AS DATETIME2(7)) AS VARCHAR(26)) AS endtime,
        Event.ID AS eventid,
        Meter.ID AS meterid,
        Meter.Name AS thesite,
        EventType.Name AS thename,
        MeterLine.LineName AS linename
    FROM
        Event JOIN
        EventType ON EventType.ID = Event.EventTypeID JOIN
        Meter ON Meter.ID = Event.MeterID JOIN
        MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Event.LineID
    WHERE
        Meter.ID IN (SELECT * FROM @MeterIDs) AND
        CAST(StartTime AS DATE) BETWEEN @startDate AND @endDate
    ORDER BY StartTime

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Mar 06, 2015>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesFaultsDetailsByDate '08/08/2014', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'day'
-- selectSitesFaultsDetailsByDate '08/08/2014 09:00 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'hour'
-- selectSitesFaultsDetailsByDate '08/08/2014 09:34 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'minute'
-- selectSitesFaultsDetailsByDate '08/08/2014 09:34:04 AM', '1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23,24,25,26,27,28,29,30,31,32,33,34,35,36,37,38,39,40,41,42,43,44,45,46,47,48,49,50,51,52,53,54,55,56,57,58,59,60,61,62,63,64,65,66,67,68,69,70,71,72,73,74,75,76,77,78,79,80,81,82,83,84,85,86,87,88,89,90,91,92,93,94,95,96,97,98,99,100,101,102,103,104,105,106,107,108,109,110,111,112,113,114,115,116,117,118,119,120,121,122,123,124,125,126,127,128,129,130,131,132,133,134,135,136,137,138,139,140,141,142,143,144,145,146,147,148,149,150,151,152,153,154,155,156,157,158,159,160,161,162,163,164,165,166,167,168,169,170,171,172,173,174,175,176,177,178,179,180,181,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,197,198,199,200,201,202,203,204,205,206,207,208,209,210,211,212,213,214,216,222,223,224,225,226,227,228,229,230,231,232,233,234,235,236,237,238,239,240,241,242,243,244,245,246,247,248,249,250,251,252,253,254,255,256,257,258,259,260,261,262,263,264,265,266,267,268,269,270,271,272,273,274,275,276,277,278,279,280,281,282,283,284,285,286,287,288,289,290,291,292,293,294,295,296,297,298,299,300,301,302,303,304,305,306,307,308,309,310,311,312,313,314,315,316,317,318,319,320,321,322,323,324,325,326,327,328,329,330,331,332,333,334,335,336,337,338,339,341,1340,1341,1342,1343,1344,1345,1346,1347,1349,1350,1351,1352,1353,1354,1355,1356,1357,1358,1359,1360,1363,1364,1365', 'S-1-5-21-4100281765-940110593-2650863885-4619', 'second'
-- =============================================
ALTER PROCEDURE [selectSitesFaultsDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000),
    @context as nvarchar(20)
AS
BEGIN
    SET NOCOUNT ON;

	DECLARE @startDate DateTime = @EventDate
	DECLARE @endDate DateTime

	if @context = 'day'
		SET @endDate = DATEADD(DAY, 1, @startDate);
	if @context = 'hour'
		SET @endDate = DATEADD(HOUR, 1, @startDate);
	if @context = 'minute'
		SET @endDate = DATEADD(MINUTE, 1, @startDate);
	if @context = 'second'
		SET @endDate = DATEADD(SECOND, 1, @startDate);


    ; WITH FaultDetail AS
    (
        SELECT
			FaultSummary.ID AS thefaultid,
            Meter.Name AS thesite,
            Meter.ShortName AS theshortsite,
            MeterLocation.ShortName AS locationname,
            Meter.ID AS themeterid,
            Line.ID AS thelineid,
            Event.ID AS theeventid,
            MeterLine.LineName AS thelinename,
			Line.AssetKey AS thelinekey,
            Line.VoltageKV AS voltage,
            CAST(CAST(Event.StartTime AS TIME) AS NVARCHAR(100)) AS theinceptiontime,
			FaultSummary.Inception AS therealinceptiontime,
            FaultSummary.FaultType AS thefaulttype,
            CASE WHEN FaultSummary.Distance = '-1E308' THEN 'NaN' ELSE CAST(CAST(FaultSummary.Distance AS DECIMAL(16,2)) AS NVARCHAR(19)) END AS thecurrentdistance,
			(SELECT COUNT(*) FROM FaultNote WHERE FaultSummary.ID = FaultNote.FaultSummaryID) as notecount,
            ROW_NUMBER() OVER(PARTITION BY Event.ID ORDER BY FaultSummary.IsSuppressed, FaultSummary.IsSelectedAlgorithm DESC, FaultSummary.Inception) AS rk
        FROM
            FaultSummary JOIN
            Event ON FaultSummary.EventID = Event.ID JOIN
            EventType ON Event.EventTypeID = EventType.ID JOIN
            Meter ON Event.MeterID = Meter.ID JOIN
            MeterLocation ON Meter.MeterLocationID = MeterLocation.ID JOIN
            Line ON Event.LineID = Line.ID JOIN
            MeterLine ON MeterLine.MeterID = Meter.ID AND MeterLine.LineID = Line.ID 
        WHERE
            EventType.Name = 'Fault' AND
            Event.StartTime >= @startDate AND Event.StartTime < @endDate AND
            Meter.ID IN (SELECT * FROM  dbo.String_to_int_table(@MeterID, ',')) AND
			Meter.ID IN (select * from authMeters(@username))
    ),
	OutageDetail AS
	(
		SELECT
			thefaultid,
			thesite,
			theshortsite,
			locationname,
			themeterid,
			thelineid,
			theeventid,
			thelinename,
			voltage,
			theinceptiontime,
			thefaulttype,
			thecurrentdistance,
			notecount,
			'[' + CAST(Outages.MirsCauseID AS VARCHAR(10)) + '] ' + Outages.CauseDesc AS causecode,
			ROW_NUMBER() OVER(PARTITION BY theeventid ORDER BY ABS(DATEDIFF(MICROSECOND, Outages.StartTime, therealinceptiontime))) AS rk
		FROM
			FaultDetail LEFT OUTER JOIN
			Outages ON
				Outages.LineId = FaultDetail.thelinekey AND
				therealinceptiontime BETWEEN DATEADD(MINUTE, -5, Outages.StartTime) AND DATEADD(MINUTE, 5, Outages.StartTime)
		WHERE rk = 1
	)
    SELECT *
    FROM OutageDetail
    WHERE rk = 1
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, July 29, 2014>
-- Description: <Description, Selects Events for a set of sites by Date>
-- selectSitesTrendingDetailsByDate '04/08/2008', '52','external'
-- =============================================
ALTER PROCEDURE [selectSitesTrendingDetailsByDate]
    -- Add the parameters for the stored procedure here
    @EventDate as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN
    SET NOCOUNT ON;

    declare @theDate as Date
    declare  @MeterIDs TABLE (ID int);

    set @theDate = CAST(@EventDate as Date)

    INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

        Select
        Meter.ID as meterid,
        Channel.ID as channelid,
        Meter.Name as sitename,
        [dbo].[AlarmType].[Name] as eventtype,
        [dbo].[MeasurementCharacteristic].[Name] as characteristic,
        [dbo].[MeasurementType].[Name] as measurementtype,
        [dbo].[Phase].[Name] as phasename,
        Channel.HarmonicGroup,
        SUM (ChannelAlarmSummary.AlarmPoints) as eventcount,
        @theDate as date

        from Channel

        join ChannelAlarmSummary on ChannelAlarmSummary.ChannelID = Channel.ID and Date = @theDate
        join Meter on Channel.MeterID = Meter.ID and [MeterID] in ( Select * from @MeterIDs)
        join [dbo].[AlarmType] on
            [dbo].[AlarmType].[ID] = ChannelAlarmSummary.AlarmTypeID and
            ([dbo].[AlarmType].[Name] = 'OffNormal' or [dbo].[AlarmType].[Name] = 'Alarm')

        join [dbo].[MeasurementCharacteristic] on Channel.MeasurementCharacteristicID = [dbo].[MeasurementCharacteristic].[ID]
        join [dbo].[MeasurementType] on Channel.MeasurementTypeID =  [dbo].[MeasurementType].ID
        join [dbo].[Phase] on Channel.PhaseID = [dbo].[Phase].ID

        Group By Meter.ID , Channel.ID , Meter.Name , [dbo].[AlarmType].[Name], [MeasurementCharacteristic].[Name] , [MeasurementType].[Name] , [dbo].[Phase].[Name], Channel.HarmonicGroup
        Order By Meter.ID

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2015>
-- Description: <Description, Selects Trending Data for a MeterID by Date, MeasurementCharacteristic, MeqasurementType, and Phase for a day>
-- selectTrendingData '03/22/2008', 1 , 20 , 1 , 3

-- =============================================
ALTER PROCEDURE [selectTrendingData]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime2,
    @MeterID int,
    @MeasurementCharacteristicID int,
    @MeasurementTypeID int,
    @PhaseID int

AS
BEGIN

    SET NOCOUNT ON;

    Declare @ChannelID as int

    Select @ChannelID = Channel.ID from Channel where MeterID = @MeterID and MeasurementCharacteristicID = @MeasurementCharacteristicID and [MeasurementTypeID] = @MeasurementTypeID and [PhaseID] = @PhaseID;

    exec selectTrendingDataByChannelIDDate @EventDate, @ChannelID;

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Trending Data for a ChannelID by Date for a day>
-- selectTrendingDataByChannelIDDate '9/15/2015', 988

-- =============================================
ALTER PROCEDURE [selectTrendingDataByChannelIDDate]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime2,
    @ChannelID int
AS
BEGIN

    SET NOCOUNT ON;

WITH TrendingDataPoint AS
(
    SELECT
        ChannelID,
        SeriesType,
        Time,
        Value
    FROM
        GetTrendingData(@EventDate, DATEADD(NANOSECOND, -100, DATEADD(DAY, 1, @EventDate)), @ChannelID, default) AS TrendingData JOIN
        (
            SELECT 0 AS ID, 'Minimum' AS SeriesType UNION
            SELECT 1 AS ID, 'Maximum' AS SeriesType UNION
            SELECT 2 AS ID, 'Average' AS SeriesType
        ) AS Series ON TrendingData.SeriesID = Series.ID
),
TrendingData AS
(
    SELECT
        ChannelID,
        Time,
        Maximum,
        Minimum,
        Average
    FROM TrendingDataPoint
    PIVOT
    (
        SUM(Value)
        FOR SeriesType IN (Maximum, Minimum, Average)
    ) AS TrendingData
)
SELECT
[TrendingData].[Time] as thedate,
[TrendingData].[Minimum] as theminimum,
[TrendingData].[Maximum] as themaximum,
[TrendingData].[Average] as theaverage,
Coalesce([dbo].[AlarmRangeLimit].[High],0) as alarmlimithigh,
Coalesce([dbo].[AlarmRangeLimit].[Low],0) as alarmlimitlow,

Coalesce((Select [dbo].[HourOfWeekLimit].[High] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] =
(select (24 * ((DatePart(dw,[TrendingData].[Time])-1))) + DatePart(hh,[TrendingData].[Time]))
and [TrendingData].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]
),0) as offlimithigh,

 Coalesce((Select[dbo].[HourOfWeekLimit].[Low] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] =
(select (24 * ((DatePart(dw,[TrendingData].[Time])-1))) + DatePart(hh,[TrendingData].[Time]))
and [TrendingData].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]
),0) as offlimitlow

FROM [TrendingData]
  left outer join [dbo].[AlarmRangeLimit] on [dbo].[AlarmRangeLimit].[ChannelID] = [TrendingData].[ChannelID]
  left outer join [dbo].[HourOfWeekLimit] on [dbo].[HourOfWeekLimit].[ChannelID] = [TrendingData].[ChannelID]

  where
      [TrendingData].[ChannelID] = @ChannelID
      and
      ([dbo].[HourOfWeekLimit].[HourOfWeek] = 0 or [dbo].[HourOfWeekLimit].[HourOfWeek] is null)
    order by [TrendingData].[Time]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Trending Data for a MeterID by Date, MeasurementCharacteristic, MeqasurementType, and Phase for 30 days back>
-- selectTrendingDataMonthly '03/22/2008', 1 , 20 , 1 , 3

-- =============================================
ALTER PROCEDURE [selectTrendingDataMonthly]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime,
    @MeterID int,
    @MeasurementCharacteristicID int,
    @MeasurementTypeID int,
    @PhaseID int

AS
BEGIN

    SET NOCOUNT ON;

SELECT
[dbo].[DailyTrendingSummary].[Date] as thedate,
[dbo].[DailyTrendingSummary].[Minimum] as theminimum,
[dbo].[DailyTrendingSummary].[Maximum] as themaximum,
[dbo].[DailyTrendingSummary].[Average] as theaverage,
[dbo].[AlarmRangeLimit].[High] as alarmlimithigh,
[dbo].[AlarmRangeLimit].[Low] as alarmlimitlow,

(Select [dbo].[HourOfWeekLimit].[High] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] = 0
and [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]) as offlimithigh,

(Select [dbo].[HourOfWeekLimit].[Low] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] = 0
and [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]) as offlimitlow

FROM [dbo].[DailyTrendingSummary]
    join [dbo].[Channel] on [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[Meter] on [dbo].[Channel].[MeterID] = [dbo].[Meter].[ID]
    join [dbo].[MeasurementType] on [dbo].[Channel].[MeasurementTypeID] = [dbo].[MeasurementType].[ID]
    join [dbo].[MeasurementCharacteristic] on [dbo].[Channel].[MeasurementCharacteristicID] = [dbo].[MeasurementCharacteristic].[ID]
    join [dbo].[Phase] on [dbo].[Channel].[PhaseID] = [dbo].[Phase].[ID]
    join [dbo].[MeterLocation] on [dbo].[Meter].[MeterLocationID] = [dbo].[MeterLocation].[ID]
    join [dbo].[AlarmRangeLimit] on [dbo].[AlarmRangeLimit].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[HourOfWeekLimit] on [dbo].[HourOfWeekLimit].[ChannelID] = [dbo].[Channel].[ID]

  where
      [dbo].[Meter].[ID] = @MeterID and
      [DailyTrendingSummary].[Date] between DATEADD( month , -1 , @EventDate) and @EventDate and
      [dbo].[MeasurementCharacteristic].[ID] = @MeasurementCharacteristicID and
      [dbo].[MeasurementType].[ID] = @MeasurementTypeID and
      [dbo].[Phase].[ID] = @PhaseID and
      [dbo].[HourOfWeekLimit].[HourOfWeek] = 0

    order by [dbo].[DailyTrendingSummary].[Date]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, Jun 26, 2014>
-- Description: <Description, Selects Trending Data for a MeterID by Date, MeasurementCharacteristic, MeqasurementType, and Phase for 30 days back>
-- [selectTrendingDataWeekly] '03/22/2008', 1 , 20 , 1 , 3

-- =============================================
ALTER PROCEDURE [selectTrendingDataWeekly]
    -- Add the parameters for the stored procedure here
    @EventDate DateTime,
    @MeterID int,
    @MeasurementCharacteristicID int,
    @MeasurementTypeID int,
    @PhaseID int

AS
BEGIN

    SET NOCOUNT ON;

SELECT
[dbo].[DailyTrendingSummary].[Date] as thedate,
[dbo].[DailyTrendingSummary].[Minimum] as theminimum,
[dbo].[DailyTrendingSummary].[Maximum] as themaximum,
[dbo].[DailyTrendingSummary].[Average] as theaverage,
[dbo].[AlarmRangeLimit].[High] as alarmlimithigh,
[dbo].[AlarmRangeLimit].[Low] as alarmlimitlow,

(Select [dbo].[HourOfWeekLimit].[High] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] = 0
and [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]) as offlimithigh,

(Select [dbo].[HourOfWeekLimit].[Low] from [dbo].[HourOfWeekLimit] where [dbo].[HourOfWeekLimit].[HourOfWeek] = 0
and [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[HourOfWeekLimit].[ChannelID]) as offlimitlow

FROM [dbo].[DailyTrendingSummary]
    join [dbo].[Channel] on [dbo].[DailyTrendingSummary].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[Meter] on [dbo].[Channel].[MeterID] = [dbo].[Meter].[ID]
    join [dbo].[MeasurementType] on [dbo].[Channel].[MeasurementTypeID] = [dbo].[MeasurementType].[ID]
    join [dbo].[MeasurementCharacteristic] on [dbo].[Channel].[MeasurementCharacteristicID] = [dbo].[MeasurementCharacteristic].[ID]
    join [dbo].[Phase] on [dbo].[Channel].[PhaseID] = [dbo].[Phase].[ID]
    join [dbo].[MeterLocation] on [dbo].[Meter].[MeterLocationID] = [dbo].[MeterLocation].[ID]
    join [dbo].[AlarmRangeLimit] on [dbo].[AlarmRangeLimit].[ChannelID] = [dbo].[Channel].[ID]
    join [dbo].[HourOfWeekLimit] on [dbo].[HourOfWeekLimit].[ChannelID] = [dbo].[Channel].[ID]

  where
      [dbo].[Meter].[ID] = @MeterID and
      [DailyTrendingSummary].[Date] between DATEADD( week , -1 , @EventDate) and @EventDate and
      [dbo].[MeasurementCharacteristic].[ID] = @MeasurementCharacteristicID and
      [dbo].[MeasurementType].[ID] = @MeasurementTypeID and
      [dbo].[Phase].[ID] = @PhaseID and
      [dbo].[HourOfWeekLimit].[HourOfWeek] = 0

    order by [dbo].[DailyTrendingSummary].[Date]

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects All Trending in the database>
-- selectTrendingForCalendar 'jwalker'
-- =============================================
ALTER PROCEDURE [selectTrendingForCalendar]
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @counter INT = 0
DECLARE @eventDate DATE = (Select max(CAST(Time AS Date)) from AlarmLog)
DECLARE @numberOfDays INT = DATEDIFF ( day , (Select min(CAST(Time AS Date)) from AlarmLog), @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp(Date DATE)

WHILE (@counter <= @numberOfDays)
BEGIN
    INSERT INTO #temp VALUES(@eventDate)
    SET @eventDate = DATEADD(DAY, 1, @eventDate)
    SET @counter = @counter + 1
END

SELECT
Date as thedate,
Offnormal as offnormal,
Alarm as alarm
FROM
(
    SELECT #temp.Date, AlarmType.Name AS AlarmTypeName, COALESCE(AlarmCount, 0) AS AlarmCount
    FROM
        #temp CROSS JOIN
        AlarmType LEFT OUTER JOIN
        (
            SELECT CAST(Time AS Date) AS AlarmDate, AlarmTypeID, COUNT(*) AS AlarmCount
            FROM AlarmLog
            join Channel on AlarmLog.ChannelID = Channel.ID and Channel.MeterID in (select * from authMeters(@username))
            GROUP BY CAST(Time AS Date), AlarmTypeID
        ) AS Alarm ON #temp.Date = Alarm.AlarmDate AND AlarmType.ID = Alarm.AlarmTypeID
) AS AlarmDate
PIVOT
(
    SUM(AlarmCount)
    FOR AlarmDate.AlarmTypeName IN (Offnormal,Alarm)
) as pvt
ORDER BY Date

DROP TABLE #temp

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, March 25, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- [selectTrendingForMeterIDByDateRange] '03/12/2008', '03/12/2014', '52', 'External'
-- =============================================
ALTER PROCEDURE [selectTrendingForMeterIDByDateRange]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)
AS
BEGIN

    SET NOCOUNT ON;

DECLARE @startDate DATE = CAST(@EventDateFrom AS DATE)
DECLARE @endDate DATE = DATEADD(DAY, 1, CAST(@EventDateTo AS DATE))

SELECT AlarmDate as thedate, COALESCE(OffNormal,0) as Offnormal, COALESCE(Alarm,0) as Alarm
FROM(
    SELECT Date AS AlarmDate, AlarmType.Name, SUM(AlarmPoints) as AlarmPoints
    FROM ChannelAlarmSummary JOIN
         Channel ON ChannelAlarmSummary.ChannelID = Channel.ID JOIN
         AlarmType ON AlarmType.ID = ChannelAlarmSummary.AlarmTypeID
    WHERE MeterID in (select * from authMeters(@username)) AND MeterID IN (SELECT * FROM String_To_Int_Table(@MeterID, ',')) AND Date >= @startDate AND Date < @endDate
    GROUP BY Date, AlarmType.Name
) AS table1
PIVOT(
    SUM(table1.AlarmPoints)
    FOR table1.Name IN(Alarm, OffNormal)
) as pvt

END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:      <Author, Jeff Walker>
-- Create date: <Create Date, June 19, 2015>
-- Description: <Description, Selects Events for a MeterID by Date for date range>
-- selectTrendingForMeterIDsByDate '05/20/2008', '06/19/2015', '32,33,10,11,34,42,91,92,1,2,3,4,93,109,110,94,12,13,116,15,16,17,18,19,20,21,22,23,24,25,26,95,96,49,97,28,98,29,30,31,27,35,36,37,84,38,39,40,41,117,43,44,5,88,45,99,80,81,100,101,46,47,51,52,53,54,89,55,56,57,58,59,60,61,48,62,63,64,65,66,67,6,7,68,69,70,71,72,73,74,75,76,50,102,103,104,105,77,78,79,118,82,106,83,85,86,87,90,111,112,113,114,115,8,9,119,14,107,120,108,121,122,123,124,125,', 'external'
-- =============================================
ALTER PROCEDURE [selectTrendingForMeterIDsByDate]
    -- Add the parameters for the stored procedure here
    @EventDateFrom as DateTime,
    @EventDateTo as DateTime,
    @MeterID as nvarchar(MAX),
    @username as nvarchar(4000)

AS
BEGIN

    SET NOCOUNT ON;

--  declare @tablecount int = (Select count(*) from AlarmLog);

--if ( @tablecount = 0 )
--Begin
--return;
--End

declare  @MeterIDs TABLE (ID int);
INSERT INTO @MeterIDs(ID) SELECT Value FROM dbo.String_to_int_table(@MeterID, ',') where Value in (select * from authMeters(@username));

DECLARE @counter INT = 0
DECLARE @eventDate DATE = CAST(@EventDateTo AS Date)
DECLARE @numberOfDays INT = DATEDIFF ( day , CAST(@EventDateFrom AS Date) , @eventDate)

SET @eventDate = DATEADD(DAY, -@numberOfDays, @eventDate)

CREATE TABLE #temp (thesiteid int, thesitename varchar(100))

INSERT INTO #temp Select [dbo].[Meter].[ID], [dbo].[Meter].[Name] from [dbo].[Meter] where [dbo].[Meter].[ID] in (Select * from @MeterIDs)

SELECT
thesiteid as siteid,
thesitename as sitename ,
COALESCE(Offnormal,0) as offnormal,
COALESCE(Alarm,0) as alarm

FROM
(
    SELECT #temp.thesiteid, #temp.thesitename , AlarmType.Name AS AlarmTypeName, COALESCE(AlarmCount, 0) AS AlarmCount
    FROM
        #temp CROSS JOIN
        AlarmType LEFT OUTER JOIN
        (
            SELECT MeterID, AlarmTypeID, Sum(AlarmPoints) AS AlarmCount FROM ChannelAlarmSummary
            join Channel on ChannelAlarmSummary.ChannelID = Channel.ID
            join Meter on Channel.MeterID = Meter.ID
            where MeterID in (Select * from @MeterIDs)
            and Date between @EventDateFrom and @EventDateTo
            GROUP BY AlarmTypeID, MeterID
        ) AS E ON AlarmType.ID = E.AlarmTypeID and E.MeterID = #temp.thesiteid
) AS AlarmDate
PIVOT
(
    SUM(AlarmCount)
    FOR AlarmDate.AlarmTypeName IN ( Alarm, Offnormal)
) as pvt
ORDER BY sitename asc

DROP TABLE #temp

END

GO


ALTER TABLE Setting
ADD DefaultValue VARCHAR(MAX) NULL
GO

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER FUNCTION [String_To_Int_Table]
(
         @list NVARCHAR(MAX)
       , @delimiter NCHAR(1) = ',' --Defaults to CSV
)
RETURNS
    @tableList TABLE(
       value INT
       )
AS

BEGIN
   DECLARE @value NVARCHAR(11)
   DECLARE @position INT

   SET @list = LTRIM(RTRIM(@list))+ ','
   set @list = REPLACE(@list, ',,', ',')
   SET @position = CHARINDEX(@delimiter, @list, 1)

   IF REPLACE(@list, @delimiter, '') <> ''
   BEGIN
          WHILE @position > 0
          BEGIN
                 SET @value = LTRIM(RTRIM(LEFT(@list, @position - 1)));
                 INSERT INTO @tableList (value)
                 VALUES (cast(@value as int));
                 SET @list = RIGHT(@list, LEN(@list) - @position);
                 SET @position = CHARINDEX(@delimiter, @list, 1);

          END
   END
   RETURN
END

GO


SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER PROCEDURE [usp_delete_cascade] (
	@base_table_name varchar(200), @base_criteria nvarchar(1000)
)
as begin
	 
	 
	 
	 
	 
	 
	 
	 
	 

	declare @to_delete table (
		id int identity(1, 1) primary key not null,
		criteria nvarchar(1000) not null,
		table_name varchar(200) not null,
		processed bit not null,
		delete_sql varchar(1000)
	)

	insert into @to_delete (criteria, table_name, processed) values (@base_criteria, @base_table_name, 0)

	declare @id int, @criteria nvarchar(1000), @table_name varchar(200)
	while exists(select 1 from @to_delete where processed = 0) begin
		select top 1 @id = id, @criteria = criteria, @table_name = table_name from @to_delete where processed = 0 order by id desc

		insert into @to_delete (criteria, table_name, processed)
			select referencing_column.name + ' in (select [' + referenced_column.name + '] from [' + @table_name +'] where ' + @criteria + ')',
				referencing_table.name,
				0
			from  sys.foreign_key_columns fk
				inner join sys.columns referencing_column on fk.parent_object_id = referencing_column.object_id 
					and fk.parent_column_id = referencing_column.column_id 
				inner join  sys.columns referenced_column on fk.referenced_object_id = referenced_column.object_id 
					and fk.referenced_column_id = referenced_column.column_id 
				inner join  sys.objects referencing_table on fk.parent_object_id = referencing_table.object_id 
				inner join  sys.objects referenced_table on fk.referenced_object_id = referenced_table.object_id 
				inner join  sys.objects constraint_object on fk.constraint_object_id = constraint_object.object_id
			where referenced_table.name = @table_name
				and referencing_table.name != referenced_table.name

		update @to_delete set
			processed = 1
		where id = @id
	end

	select 'print ''deleting from ' + table_name + '...''; delete from [' + table_name + '] where ' + criteria from @to_delete order by id desc
end

GO